It is quite natural to view Oracle’s In-Memory Option in context of the relational model; however, the In-Memory Option supports the JSON model at the same time as well.
Oracle JSON Support
As shown earlier in this blog, the Oracle 12c database supports JSON natively [http://docs.oracle.com/database/121/ADXDB/json.htm#ADXDB6246] and incorporates JSON access into SQL so that JSON structures can be accessed through SQL directly. In addition, in a single SQL statement, JSON structures as well as relational tables can be accessed at the same time. Please see the documentation and the other blog entries for more details.
Oracle In-Memory Option
The In-Memory Option [http://www.oracle.com/us/corporate/features/database-in-memory-option/] was introduced in the previous two blog entries and those discussed a relational example as well as queries that allow to introspect the meta data and status of the In-Memory Option processing. It gave an overview as well as the rationale why using the In-Memory Option for analytic queries is advantageous over regular relational processing (columnar representation of data in main memory).
Combination: JSON processing using In-Memory Option
Analytics in context of JSON structures would benefit from In-Memory Option support as well. Many applications based on JSON structures usually have to support some form of analytics. The In-Memory Option supports aggregation functionality on JSON structures as well as on relational tables.
In the following, an example is introduced that creates a table containing a JSON structure, enables it for In-Memory Option support and shows a few simple analytics queries.
Example Table with JSON Structure
The following declares a sample table with a column containing a JSON structure.
DROP TABLE js_players; CREATE TABLE js_players ( player_id NUMBER NOT NULL, player_name VARCHAR(255), games VARCHAR(4000) CONSTRAINT games_ensure_json CHECK (games IS JSON (STRICT WITH UNIQUE KEYS)));
Table Population
In order to have a large data set the following block creates rows containing JSON structures and inserting them into the above declared table.
DECLARE counter NUMBER; player_name VARCHAR(128); games_value VARCHAR (256); BEGIN counter := 0; LOOP counter := counter + 1; player_name := 'Divvon' || '_' || counter; games_value := '{ "games": [{"name":"tic-tac-toe", "points":' || counter *10 || '}, {"name":"one-two-three", "points":' || counter * 100 || '} ]}'; INSERT INTO js_players VALUES (counter, player_name, games_value); EXIT WHEN counter = 1000000; END LOOP; COMMIT; RETURN; END;
An example JSON document looks like this:
{"games": [{"name":"tic-tac-toe", "points":750}, {"name":"one-two-three", "points":7500} ]}
Enabling In-Memory Option
This statement enables the In-Memory Option for the table containing JSON structures:
ALTER TABLE js_players inmemory priority critical;
Aggregation Queries
The following queries show aggregation over elements of the JSON structures. Each query extracts all ‘points’ values from the JSON structure (since every document might have several ‘points’ fields in the array of ‘games’) and makes is accessible as ‘pts.points’. Then it aggregates over this structure. The first query aggregates over all rows, whereas the second query is selecting only a few rows based on ‘player_name’.
SELECT DISTINCT p.player_name, SUM(pts.points) sum_points, MIN(pts.points) min_points, MAX(pts.points) max_points, AVG(pts.points) avg_points, COUNT(*) FROM js_players p, json_table(p.games, '$.games[*]' COLUMNS (points VARCHAR2(32 CHAR) PATH '$.points')) AS pts GROUP BY p.player_name ORDER BY sum_points DESC;
SELECT DISTINCT p.player_name, SUM(pts.points) sum_points, MIN(pts.points) min_points, MAX(pts.points) max_points, AVG(pts.points) avg_points, COUNT(*) FROM js_players p, json_table(p.games, '$.games[*]' COLUMNS (points VARCHAR2(32 CHAR) PATH '$.points')) AS pts WHERE p.player_name = 'Divvon_204' OR p.player_name = 'Divvon_206' GROUP BY p.player_name ORDER BY sum_points DESC;
Summary
Oracle’s In-Memory Option, because it not only supports the relational model, but also the JSON model, is an interesting alternative to analytics in context of JSON data sets. This blog has shown an example of how to combine JSON structures and the In-Memory Option in order to be able to run analytics queries.
Go SQL!
Disclaimer
The views expressed on this blog are my own and do not necessarily reflect the views of Oracle.