diff --git a/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/01.json-collection-tables.sql b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/01.json-collection-tables.sql new file mode 100644 index 000000000..bcbb00ccf --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/01.json-collection-tables.sql @@ -0,0 +1,140 @@ + + +------------------------------------------------------------------------------------------------------- +----------- SAMPLE Queries using SQL/JSON JSON_VALUE,JSON_EXISTS,JSON_QUERY ------------------------ +------------------------------------------------------------------------------------------------------- +------------------------------------------------------------------------------------------------------- +-- dot notation: "_id", "resid", "reference", "requestor" +------------------------------------------------------------------------------------------------------- + SELECT po.DATA."_id" "_id" + , po.resid resid + , po.DATA.Reference reference + , po.DATA.Requestor requestor + FROM PURCHASEORDERS po where rownum < 2; + +/* +_id RESID REFERENCE REQUESTOR +_____________________________ _____________________________ ______________________ ___________________ +"681778538527e06b8c86e698" 08681778538527E06B8C86E698 "SVOLLMAN-20140523" "Shanta Vollman" +*/ + +------------------------------------------------------------------------------------------------------- +-- JSON_SERIALIZE, JSON_EXISTS +------------------------------------------------------------------------------------------------------- + +SELECT JSON_SERALIZE(DATA PRETTY ORDERED) + FROM PURCHASEORDERS + WHERE JSON_EXISTS(DATA, '$?(@.PONumber == $V1)' + PASSING '25' AS "V1") +; + /* { + "_id" : "6810e62338848c2330102b9a", + "CostCenter" : "A50", + "PONumber" : 25, + "Reference" : "TGATES-20140511", + "Requestor" : "Timothy Gates", + "Special Instructions" : "Priority Overnight", + "User" : "TGATES", + "ShippingInstructions" : + { + "name" : "Timothy Gates", + "Address" : + { + "city" : "South San Francisco", + "country" : "United States of America", + "state" : "CA", + "street" : "200 Sporting Green", + "zipCode" : 99236 + .................................... +}*/ +------------------------------------------------------------------------------------------------------- +-- JSON_EXISTS. Query by "_id" +------------------------------------------------------------------------------------------------------- +SELECT DATA + FROM PURCHASEORDERS + WHERE JSON_EXISTS(DATA, '$?(@._id == $V1)' + PASSING '681778538527e06b8c86e698' AS "V1") +; + +------------------------------------------------------------------------------------------------------- +-- JSON_VALUE. Extracting three POs references +------------------------------------------------------------------------------------------------------- + +SELECT JSON_VALUE (DATA, '$.Reference') "PO Reference" + FROM PURCHASEORDERS where ROWNUM < 4; +/* +PO Reference +____________________ +SVOLLMAN-20140531 +TFOX-20140511 +GGEONI-20141114 +*/ +------------------------------------------------------------------------------------------------------- +--JSON_EXISTS. Extracting LineItems with UPCCode = 85391628927 +------------------------------------------------------------------------------------------------------- +SELECT JSON_SERIALIZE(DATA pretty) FROM PURCHASEORDERS + WHERE JSON_EXISTS (DATA,'$.LineItems.Part?(@.UPCCode == $V1)' + PASSING '85391628927' AS "V1"); +/* +{ + "_id" : "68177b1d8527e06b8c873477", + "PONumber" : 9947, + "Reference" : "GHIMURO-20141128", + "Requestor" : "Guy Himuro", + "User" : "GHIMURO", + "CostCenter" : "A30", + "ShippingInstructions" : + { + "name" : "Guy Himuro", + "Address" : + { + "street" : "2004 Blacksmiths Court", + "city" : "Seattle", + "state" : "WA", + "zipCode" : 98199, + ................... + +*/ +------------------------------------------------------------------------------------------------------- +--- Extracting LineItems with unit price less than 19 +------------------------------------------------------------------------------------------------------- +SELECT DATA FROM PURCHASEORDERS + WHERE JSON_EXISTS(DATA '$.LineItems.Part?(@.UnitPrice < $V1)' + PASSING '19' AS "V1"); +------------------------------------------------------------------------------------------------------- +--- Extracting Purchase Order 25 +------------------------------------------------------------------------------------------------------- +SELECT DATA FROM PURCHASEORDERS + WHERE JSON_EXISTS(DATA, '$?(@.PONumber == $V1)' + PASSING '25' AS "V1" ); +------------------------------------------------------------------------------------------------------- +-- Extracting Orders allowing Partial Shipments - Boolean DATA type +------------------------------------------------------------------------------------------------------- +SELECT DATA + FROM PURCHASEORDERS + WHERE JSON_VALUE (DATA, '$.AllowPartialShipment' + RETURNING BOOLEAN) +------------------------------------------------------------------------------------------------------- +-- Shipping instructions : state CA +------------------------------------------------------------------------------------------------------- +SELECT DATA FROM PURCHASEORDERS + WHERE JSON_EXISTS(DATA,'$.ShippingInstructions?(@.Address.state == $V1)' + PASSING 'CA' AS "V1"); +------------------------------------------------------------------------------------------------------- +-- Shipping instructions : name Timothy Gates +------------------------------------------------------------------------------------------------------- +SELECT DATA FROM PURCHASEORDERS + WHERE JSON_EXISTS( DATA, '$.ShippingInstructions?(@.name == $V1)' + PASSING 'Timothy Gates' AS "V1"); +------------------------------------------------------------------------------------------------------- +-- JSON Query +------------------------------------------------------------------------------------------------------- +SELECT JSON_QUERY(DATA,'$.ShippingInstructions') + FROM PURCHASEORDERS + where JSON_VALUE(DATA,'$.PONumber' returning number)=1000; + +/* +{"name":"Charles Johnson","Address":{"street":"Magdalen Centre, The Isis Science Park","city":"Oxford","county":"Oxon." +,"postcode":"OX9 9ZB","country":"United Kingdom"},"Phone":[{"type":"Office","number":"66-555-3120"}]} +*/ + diff --git a/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/02.json-collection-views.sql b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/02.json-collection-views.sql new file mode 100644 index 000000000..65c19a337 --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/02.json-collection-views.sql @@ -0,0 +1,213 @@ + + +-- PURCHASEORDERS - JSON collection table +-- PURCHASEORDER_CV, PURCHASEORDER_TOT_PRC_CV, PURCHASEORDER_AVG_PRC_CV - JSON collection views + + +--------------------------------------------------------------------------------- +---------------------------- JSON RELATIONAL VIEW ------------------------------- +--------------------------------------------------------------------------------- +CREATE or REPLACE VIEW PURCHASEORDER_V AS + SELECT ponumber, requestor, special, address + FROM PURCHASEORDERS, + json_table (DATA, '$' + COLUMNS (ponumber number PATH '$.PONumber', + requestor varchar2(32) PATH '$.Requestor', + special varchar2(10) PATH '$."Special Instructions"', + address JSON PATH '$.ShippingInstructions.Address')) jt +; + + +DESC PURCHASEORDER_V +/* +Name Null? Type + +--------- ----- ------------ +PONUMBER NUMBER +REQUESTOR VARCHAR2(32) +SPECIAL VARCHAR2(10) +ADDRESS JSON +*/ + +SELECT * FROM PURCHASEORDER_V ORDER BY PONUMBER; +/* + PONUMBER REQUESTOR SPECIAL ADDRESS +___________ _________________ __________ _______________________________________________________________________________________________________________________________________ + 1 Martha Sullivan {"street":"200 Sporting Green","city":"South San Francisco","state":"CA","zipCode":99236,"country":"United States of America"} + 2 Martha Sullivan {"street":"200 Sporting Green","city":"South San Francisco","state":"CA","zipCode":99236,"country":"United States of America"} + ............................................................................................................................... + + */ + +SELECT po_v.ponumber, po_v.REQUESTOR , po_v.SPECIAL, po_v.address.city FROM +PURCHASEORDER_V po_v WHERE ponumber =7; +/* + PONUMBER REQUESTOR SPECIAL CITY +___________ ______________ _____________ ________________________ + 7 Vance Jones Hand Carry "South San Francisco" */ + +-- using a CTE (Common Table Expression) +WITH po_cte AS + (SELECT ponumber, requestor, special, address + FROM PURCHASEORDERS, + JSON_TABLE (DATA, '$' + COLUMNS (ponumber number PATH '$.PONumber', + requestor varchar2(32) PATH '$.Requestor', + special varchar2(32) PATH '$."Special Instructions"', + address JSON PATH '$.ShippingInstructions.Address')) jt + ) +SELECT ponumber, requestor, special, address FROM po_cte; + +--------------------------------------------------------------------------------- +---------------------------- JSON COLLECTION VIEW ------------------------------- +--------------------------------------------------------------------------------- + + +-- JSON collection view with nested path +CREATE OR REPLACE JSON COLLECTION VIEW PURCHASEORDER_CV AS + SELECT JSON {ponumber, requestor, special, itemnumber,itemdesc,unitprice, upccode, quantity} + FROM PURCHASEORDERS, + JSON_TABLE (DATA, '$' + COLUMNS (ponumber number PATH '$.PONumber', + requestor varchar2(32) PATH '$.Requestor', + special varchar2(30) PATH '$."Special Instructions"', + NESTED PATH '$.LineItems[*]' + COLUMNS + ( itemnumber number PATH '$.ItemNumber', + quantity number PATH '$.Quantity', + NESTED PATH '$.Part[*]' + COLUMNS ( + itemdesc varchar2(50) PATH '$.Description', + upccode number PATH '$.UPCCode', + unitprice number PATH '$.UnitPrice') + ) + )) + ; + + +SELECT po.DATA.requestor + ,po.DATA.ponumber + ,po.DATA.itemnumber + ,po.DATA.itemdesc + ,po.DATA.unitprice + ,po.DATA.quantity + FROM PURCHASEORDER_CV po +WHERE po.DATA.ponumber=25 +; +/* +REQUESTOR PONUMBER ITEMNUMBER ITEMDESC UNITPRICE QUANTITY +__________________ ___________ _____________ _________________________________________ ____________ ___________ +"Timothy Gates" 25 1 "The Land Before Time: The Big Freeze" 27.95 2 +"Timothy Gates" 25 2 "Winning" 19.95 1 +"Timothy Gates" 25 3 "Falling Down" 19.95 5 +*/ +---------------------------------------------------------------------------------------------------------------- +----------------JSON COLLECTION VIEW with AGGREGATE functions +---------------------------------------------------------------------------------------------------------------- + +-- JSON collection view with SUM +CREATE OR REPLACE JSON COLLECTION VIEW PURCHASEORDER_TOT_PRC_CV AS + SELECT JSON {jt.ponumber, jt.requestor, jt.total_price} + FROM ( + SELECT ROUND (SUM(unitprice * quantity),2) total_price + , ponumber + , requestor + FROM PURCHASEORDERS, + JSON_TABLE(DATA, '$' error on error null on empty + COLUMNS (ponumber number PATH '$.PONumber', + requestor varchar2(32) PATH '$.Requestor', + special varchar2(30) PATH '$."Special Instructions"', + NESTED PATH '$.LineItems[*]' + COLUMNS + ( itemnumber number PATH '$.ItemNumber', + quantity number PATH '$.Quantity', + NESTED PATH '$.Part[*]' + COLUMNS ( + itemdesc CLOB PATH '$.Description', + upccode number PATH '$.UPCCode', + unitprice number PATH '$.UnitPrice') + ) + )) + GROUP BY requestor, ponumber + )jt +; + +SELECT po.DATA.ponumber, po.DATA.requestor,po.DATA.total_price + FROM PURCHASEORDER_TOT_PRC_CV po + WHERE po.DATA.ponumber=25; + + /* +PONUMBER REQUESTOR TOTAL_PRICE +___________ __________________ ______________ +25 "Timothy Gates" 175.6 + + */ + +--------------------------------------------------------------------------------- +----------------JSON COLLECTION VIEWS with WINDOW function ---------------------- +--------------------------------------------------------------------------------- +-- Avgeare of Total items price + + +CREATE OR REPLACE JSON COLLECTION VIEW PURCHASEORDER_AVG_PRC_CV AS + SELECT JSON { + jt.ponumber, + jt.itemnumber, + jt.itemdesc, + jt.quantity, + jt.unitprice, + jt.total_item_price, + jt.average_total_item_price} + FROM ( + SELECT + ponumber, + itemnumber, + itemdesc, + quantity, + unitprice, + ROUND (unitprice * quantity,2) total_item_price, + ROUND (avg(unitprice * quantity) over (partition by ponumber),2) average_total_item_price + FROM PURCHASEORDERS, + JSON_TABLE(DATA, '$' error on error null on empty + COLUMNS (ponumber number PATH '$.PONumber', + requestor varchar2(32) PATH '$.Requestor', + special varchar2(30) PATH '$."Special Instructions"', + NESTED PATH '$.LineItems[*]' + COLUMNS + ( itemnumber number PATH '$.ItemNumber', + quantity number PATH '$.Quantity', + NESTED PATH '$.Part[*]' + COLUMNS ( + itemdesc CLOB PATH '$.Description', + --itemdesc varchar2(100) PATH '$.Description', + upccode number PATH '$.UPCCode', + unitprice number PATH '$.UnitPrice') + ) + ) + ) + ) jt +; + + +SELECT po.DATA.ponumber, + po.DATA.itemnumber, + po.DATA.itemdesc, + po.DATA.quantity, + po.DATA.unitprice, + po.DATA.total_item_price, + po.DATA.average_total_item_price + FROM PURCHASEORDER_AVG_PRC_CV po + WHERE po.DATA.ponumber=25 +; + +/* + +PONUMBER ITEMNUMBER ITEMDESC QUANTITY UNITPRICE TOTAL_ITEM_PRICE AVERAGE_TOTAL_ITEM_PRICE +___________ _____________ _________________________________________ ___________ ____________ ___________________ ________________________ +25 1 "The Land Before Time: The Big Freeze" 2 27.95 55.9 58.53 +25 2 "Winning" 1 19.95 19.95 58.53 +25 3 "Falling Down" 5 19.95 99.75 58.53 +*/ + + + diff --git a/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/03.json-duality-views.sql b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/03.json-duality-views.sql new file mode 100644 index 000000000..96f595085 --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/03.json-duality-views.sql @@ -0,0 +1,86 @@ + +--------------------------------------------------------------------------------- +-- CUSTOMER_HISTORY_SALES_DV - JSON RELATIONAL DUALITY Views +-- CUSTOMERS, SALES, PRODUCTS relational tables, SH sample schema +---------------------------------------------------------------------------------- + +CREATE FORCE NONEDITIONABLE JSON RELATIONAL DUALITY VIEW CUSTOMER_HISTORY_SALES_DV + AS SELECT JSON { + 'quantitySold' : s.QUANTITY_SOLD, + 'amountSold' : s.AMOUNT_SOLD, + '_id' : s.SALES_ID, + 'products' : + ( SELECT JSON { + 'prodId' : p.PROD_ID, + 'prodName' : p.PROD_NAME, + 'prodDesc' : p.PROD_DESC, + 'prodCategory' : p.PROD_CATEGORY + } + FROM PRODUCTS p + WHERE p.PROD_ID = s.PROD_ID + ), + 'customers' : + ( SELECT JSON { + 'custId' : c.CUST_ID, + 'custFirstName' : c.CUST_FIRST_NAME, + 'custLastName' : c.CUST_LAST_NAME, + 'custPostalCode' : c.CUST_POSTAL_CODE, + 'custEmail' : c.CUST_EMAIL WITH UPDATE + } + FROM CUSTOMERS c + WHERE c.CUST_ID = s.CUST_ID + ) + } + FROM SALES s +; + +SELECT dv.DATA.customers.custId CUST_ID, + dv.DATA.amountSold AMOUNT_SOLD, + dv.DATA.customers.custEmail CUST_EMAIL, + dv.DATA.products.prodId PROD_ID, + dv.DATA.products.prodDesc PROD_DESC, + dv.DATA.products.prodCategory CATEGORY + FROM CUSTOMER_HISTORY_SALES_DV dv + WHERE dv.DATA.customers.custId = 8696 +; +/* +CUST_ID AMOUNT_SOLD CUST_EMAIL PROD_ID PROD_DESC CATEGORY +__________ ______________ __________________________________ __________ ____________________________________________ ______________________ +8696 51.97 "Snodgrass@company.example.com" 127 "Genuine Series MIX Wood Bat" "Baseball" +8696 1552.83 "Snodgrass@company.example.com" 18 "Lithium Electric Golf Caddy" "Golf" +8696 48.36 "Snodgrass@company.example.com" 42 "New Zealand Cricket Team" "Cricket" +8696 49.66 "Snodgrass@company.example.com" 40 "West Indies Team" "Cricket" +8696 48.36 "Snodgrass@company.example.com" 45 "English Cricket Team" "Cricket" +8696 48.36 "Snodgrass@company.example.com" 41 "South African Team" "Cricket" +8696 54.35 "Snodgrass@company.example.com" 35 "Catchers Mitt" "Baseball" +8696 16.69 "Snodgrass@company.example.com" 125 "Cricket Bucket Hat" "Cricket" +8696 11.38 "Snodgrass@company.example.com" 30 "Cricket Bat - Linseed Oil" "Cricket" +8696 45.71 "Snodgrass@company.example.com" 27 "Bucket of 24 Synthetic Baseballs" "Baseball" +8696 9.36 "Snodgrass@company.example.com" 30 "Cricket Bat - Linseed Oil" "Cricket" +8696 53.89 "Snodgrass@company.example.com" 36 "12\" Premium Ser +*/ + +-- SUM sales + +WITH CTE as +(SELECT dv.DATA.customers.custId CUST_ID, + dv.DATA.amountSold AMOUNT_SOLD, + dv.DATA.customers.custEmail CUST_EMAIL, + dv.DATA.products.prodId PROD_ID, + dv.DATA.products.prodDesc PROD_DESC, + dv.DATA.products.prodCategory CATEGORY +FROM CUSTOMER_HISTORY_SALES_DV dv +WHERE dv.DATA.customers.custId = 8696) +SELECT CUST_ID,CUST_EMAIL,PROD_DESC, SUM(AMOUNT_SOLD), CATEGORY FROM CTE GROUP BY CUST_ID,CUST_EMAIL,PROD_DESC, CATEGORY +; +/* +CUST_ID CUST_EMAIL PROD_DESC SUM(AMOUNT_SOLD) CATEGORY +__________ __________________________________ _______________________________________ ___________________ ____________ +8696 "Snodgrass@company.example.com" "Tennis Balls 12 Pack" 47.36 "Tennis" +8696 "Snodgrass@company.example.com" "Tennis Balls Heavy Duty Felt 3 can" 20.98 "Tennis" +8696 "Snodgrass@company.example.com" "Tennis Strings Natural Gut" 100.16 "Tennis" +8696 "Snodgrass@company.example.com" "West Indies Team" 97.59 "Cricket" +8696 "Snodgrass@company.example.com" "Wicket Keeper Gloves" 18.86 "Cricket" + +46 rows selected. +*/ \ No newline at end of file diff --git a/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/04.json-materialized-views.sql b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/04.json-materialized-views.sql new file mode 100644 index 000000000..3eee910ed --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/04.json-materialized-views.sql @@ -0,0 +1,320 @@ + + + +--------------------------------------------------------------------------------- +-- Materialized Views over JSON Data with ROWID and PRIMARY KEY +-- PURCHASEORDERS collection table +--------------------------------------------------------------------------------- + +-- Creating Materialized view with ROWID +DROP MATERIALIZED VIEW JSON_PO_MV; +CREATE MATERIALIZED VIEW JSON_PO_MV +BUILD IMMEDIATE +REFRESH FAST ON STATEMENT WITH ROWID +AS +SELECT po.rowid as id, jt.* +FROM PURCHASEORDERS po, + JSON_TABLE(DATA, '$' error on error null on empty + COLUMNS (ponumber number PATH '$.PONumber', + requestor varchar2(32) PATH '$.Requestor', + special varchar2(30) PATH '$."Special Instructions"', + NESTED PATH '$.LineItems[*]' + COLUMNS + ( itemnumber number PATH '$.ItemNumber', + quantity number PATH '$.Quantity', + NESTED PATH '$.Part[*]' + COLUMNS ( + itemdesc varchar2(50) PATH '$.Description', + upccode number PATH '$.UPCCode', + unitprice number PATH '$.UnitPrice') + ) + )) jt; + + +-- Explain Plan +EXPLAIN PLAN FOR +SELECT * FROM JSON_PO_VIEW_NESTED; +SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY()); + + +-- Creating Materialized view with PK +DROP MATERIALIZED VIEW JSON_PO_MV_PK; +CREATE MATERIALIZED VIEW JSON_PO_MV_PK BUILD IMMEDIATE +REFRESH FAST ON STATEMENT WITH PRIMARY KEY +AS SELECT po.resid, jt.* +FROM PURCHASEORDERS po, + JSON_TABLE(po.DATA, '$' error on error null on empty + COLUMNS + (poNum varchar2(10) PATH '$.PONumber', + userid VARCHAR2(10) PATH '$.User', + NESTED PATH '$.LineItems[*]' + COLUMNS + (itemnumber number PATH '$.ItemNumber', + itemQuantity varchar2(10) PATH '$.Quantity', + NESTED PATH '$.Part[*]' + COLUMNS ( itename varchar2(50) PATH '$.Description', + upccode varchar2(10) PATH '$.UPCCode', + unitprice number PATH '$.UnitPrice' + ) + ) + )) jt; + +DROP MATERIALIZED VIEW JSON_PO_MV_PK; +CREATE MATERIALIZED VIEW JSON_PO_MV_PK BUILD IMMEDIATE +REFRESH FAST ON STATEMENT WITH PRIMARY KEY +AS SELECT po.resid, po.* +FROM PURCHASEORDERS po, + JSON_TABLE (po.DATA, '$' error on error null on empty + COLUMNS (ponumber number PATH '$.PONumber', + requestor varchar2(32) PATH '$.Requestor', + special varchar2(30) PATH '$."Special Instructions"', + NESTED PATH '$.LineItems[*]' + COLUMNS + ( itemnumber number PATH '$.ItemNumber', + NESTED PATH '$.Part[*]' + COLUMNS ( + itemdesc varchar2(50) PATH '$.Description', + upccode number PATH '$.UPCCode', + unitprice number PATH '$.UnitPrice') + ))); + + +EXPLAIN PLAN FOR SELECT * FROM JSON_PO_MV_PK; +select PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY()); + +set define off +explain plan for SELECT po.data FROM purchaseorders po + WHERE json_exists(po.data, + '$?(@.PONumber == 25 + && exists(@.LineItems[*]?( + @.Part.UPCCode == 85391264828 + && @.Quantity > 3))'); + + +select PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY()); + +explain plan for SELECT po.data FROM purchaseorders po + WHERE json_exists(po.data, + '$?(@.PONumber == 25 + && exists(@.LineItems[*]?( + @.Part[*]?(@.UPCCode == 85391264828 + && @.Quantity > 3)))'); + + + +------- Query Rewrite + +CREATE MATERIALIZED VIEW mv_for_query_rewrite + BUILD IMMEDIATE + REFRESH FAST ON STATEMENT WITH PRIMARY KEY + AS SELECT po.resid, jt.* + FROM purchaseorders po, + json_table(po.data, '$' ERROR ON ERROR NULL ON EMPTY + COLUMNS ( + po_number NUMBER PATH '$.PONumber', + userid VARCHAR2(10) PATH '$.User', + NESTED PATH '$.LineItems[*]' + COLUMNS ( + itemno NUMBER PATH '$.ItemNumber', + description VARCHAR2(256) PATH '$.Part.Description', + upc_code NUMBER PATH '$.Part.UPCCode', + quantity NUMBER PATH '$.Quantity', + unitprice NUMBER PATH '$.Part.UnitPrice'))) jt; + +---- && +SET DEFINE OFF + +EXPLAIN PLAN for SELECT po.data FROM purchaseorders po + WHERE JSON_EXISTS(po.data, + '$?(@.PONumber == 25 + && exists(@.LineItems[*]?( + @.Part.UPCCode == 85391264828 + && @.Quantity > 3)))'); + +SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY()); + +SELECT JSON_SERIALIZE(po.data) FROM purchaseorders po WHERE json_exists(po.data, + '$?(@.User == "ABULL" + && exists(@.LineItems[*]?( + @.Part.UPCCode == 85391628927 + && @.Quantity > 3)))'); + +-- explain plan +explain plan for SELECT po.data FROM purchaseorders po + WHERE json_exists(po.data, + '$?(@.User == "ABULL" + && exists(@.LineItems[*]?( + @.Part.UPCCode == 85391628927 + && @.Quantity > 3)))'); + + SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY()); + + +/* +Plan hash value: 1405009755 + +----------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | +----------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | 1 | 5137 | 131 (2)| 00:00:01 | +| 1 | NESTED LOOPS | | 1 | 5137 | 131 (2)| 00:00:01 | +| 2 | SORT UNIQUE | | 1 | 33 | 129 (1)| 00:00:01 | +|* 3 | MAT_VIEW ACCESS FULL | MV_FOR_QUERY_REWRITE | 1 | 33 | 129 (1)| 00:00:01 | +| 4 | TABLE ACCESS BY INDEX ROWID| PURCHASEORDERS | 1 | 5104 | 1 (0)| 00:00:01 | +|* 5 | INDEX UNIQUE SCAN | SYS_C008438 | 1 | | 0 (0)| 00:00:01 | +----------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 3 - filter("SYS_JMV_1"."UPC_CODE"=85391628927 AND "SYS_JMV_1"."USERID"='ABULL' AND + "SYS_JMV_1"."QUANTITY">3) + 5 - access("SYS_JMV_1"."RESID"=JSON_VALUE("DATA" /*+ LOB_BY_VALUE FORMAT OSON , + '$._id' RETURNING ANY ORA_RAWCOMPARE(2000) NO ARRAY ERROR ON ERROR TYPE(LAX) )) + +Note +----- + - dynamic statistics used: dynamic sampling (level=2) + +24 rows selected. + +You can tell whether the materialized view is used for a particular query by examining the execution plan. +If it is, then the plan refers to mv_for_query_rewrite. For example: +|* 4| MAT_VIEW ACCESS FULL | MV_FOR_QUERY_REWRITE |1|51|3(0)|00:00:01| +*/ +--- +-- Index on a MV +drop INDEX MV_IDx; +CREATE INDEX mv_idx ON mv_for_query_rewrite(userid, + upc_code, + quantity); + +explain plan for SELECT po.data FROM purchaseorders po + WHERE json_exists(po.data, + '$?(@.User == "ABULL" + && exists(@.LineItems[*]?( + @.Part.UPCCode == 85391628927 + && @.Quantity > 3)))'); + +SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY()); +/* +PLAN_TABLE_OUTPUT +________________________________________________________________________________________________________ +Plan hash value: 1405009755 + +----------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | +----------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | 1 | 5137 | 131 (2)| 00:00:01 | +| 1 | NESTED LOOPS | | 1 | 5137 | 131 (2)| 00:00:01 | +| 2 | SORT UNIQUE | | 1 | 33 | 129 (1)| 00:00:01 | +|* 3 | MAT_VIEW ACCESS FULL | MV_FOR_QUERY_REWRITE | 1 | 33 | 129 (1)| 00:00:01 | +| 4 | TABLE ACCESS BY INDEX ROWID| PURCHASEORDERS | 1 | 5104 | 1 (0)| 00:00:01 | +|* 5 | INDEX UNIQUE SCAN | SYS_C008438 | 1 | | 0 (0)| 00:00:01 | +----------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 3 - filter("SYS_JMV_1"."UPC_CODE"=85391628927 AND "SYS_JMV_1"."USERID"='ABULL' AND + "SYS_JMV_1"."QUANTITY">3) + 5 - access("SYS_JMV_1"."RESID"=JSON_VALUE("DATA" /*+ LOB_BY_VALUE * FORMAT OSON , + '$._id' RETURNING ANY ORA_RAWCOMPARE(2000) NO ARRAY ERROR ON ERROR TYPE(LAX) )) + +Note +----- + - dynamic statistics used: dynamic sampling (level=2) + +24 rows selected. +*/ + + +-- Materialized view aggregation +DROP MATERIALIZED VIEW mv_for_aggregation; +CREATE MATERIALIZED VIEW mv_for_aggregation + AS SELECT jt.po_number, sum(jt.quantity * jt.unitprice) + FROM PURCHASEORDERS po, + json_table(po.data, '$' ERROR ON ERROR NULL ON EMPTY + COLUMNS ( + po_number NUMBER PATH '$.PONumber', + userid VARCHAR2(10) PATH '$.User', + NESTED PATH '$.LineItems[*]' + COLUMNS ( + itemno NUMBER PATH '$.ItemNumber', + description VARCHAR2(256) PATH '$.Part.Description', + upc_code NUMBER PATH '$.Part.UPCCode', + quantity NUMBER PATH '$.Quantity', + unitprice NUMBER PATH '$.Part.UnitPrice'))) jt + GROUP BY (jt.po_number); + + + +explain plan for select * from mv_for_aggregation; + +select * from SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY()); + +-- MV example 2 +-- SALES JSON collection Tabke +drop table if exists SALES; +create JSON collection table if not exists SALES; + +-- populate the JSON collection table with 2 documents: + +insert into SALES values ('{ "_id" : 1, "item" : "Espresso", "price" : 5, "size": "Short", "quantity" : 22, "date" : "2025-04-15T08:00:00Z"}'); +insert into SALES values ('{ "_id" : 2, "item" : "Finlandia", "price" : 6, "old_price" : 4, "size": "Grande","quantity" : 100, "date" : "2025-01-10T10:00:00Z", +"CoffeeItems" : [{ "Details" : { "Description" : "Coffee from Helsinki", + "UnitPrice" : 6, + "Code" : 35801}, + "Quantity" : 50.0 }, + { "Details" : { "Description" : "Coffee from Tampere", + "UnitPrice" : 6, + "Code" : 35802}, + "Quantity" : 30.0 } , + { "Details" : { "Description" : "Coffee from Turku", + "UnitPrice" : 6, + "Code" : 35803}, + "Quantity" : 20.0 }] }'); + +commit work; + +drop MATERIALIZED VIEW if exists sales_mv; + +CREATE MATERIALIZED VIEW sales_mv + BUILD IMMEDIATE + REFRESH FORCE + START WITH TRUNC(SYSDATE+1)+12/24 + NEXT SYSDATE+1 + WITH ROWID + AS SELECT jt.* + FROM sales s, + json_table(s.data, '$' ERROR ON ERROR NULL ON EMPTY + COLUMNS ( + item_id NUMBER PATH '$._id', + item_name VARCHAR2(16) PATH '$.item', + item_price NUMBER PATH '$.price', + NESTED PATH '$.CoffeeItems[*]' + COLUMNS ( + details_description VARCHAR2(32) PATH '$.Details.Description', + details_code NUMBER PATH '$.Details.Code'))) jt; + +CREATE INDEX mv_det_code_idx ON sales_mv(details_code); + +select * from SALES_MV; +-- update the price +exec DBMS_MVIEW.REFRESH('SALES_MV'); +SELECT * FROM sales_mv s WHERE s.details_code is not null; +explain plan for SELECT * FROM sales_mv s WHERE s.details_code is not null; +select * from dbms_xplan.display(); + +CREATE OR REPLACE JSON COLLECTION VIEW sales_json_cv AS + SELECT JSON {'_id' : item_id, + 'coffee_location' : details_description, + 'code' : details_code} + FROM sales_mv + WHERE details_code is not NULL; + +select * from SALES_JSON_CV; + + + + diff --git a/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/05.json-partitioning.sql b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/05.json-partitioning.sql new file mode 100644 index 000000000..134834295 --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/05.json-partitioning.sql @@ -0,0 +1,329 @@ + +--------------------------------------------------------------------------------- +-- PARTITIONING and INDEXING +-- PURCHASEORDERS collection table +-- JSON RELATIONAL DUALITY Views +-- CUSTOMERS /PRODUCTS +--------------------------------------------------------------------------------- +-------------------------------------------------------------------------------- +---------------------------- PARTITIONING -------------------------------------- +-------------------------------------------------------------------------------- +DROP TABLE ORDERS; +CREATE JSON COLLECTION TABLE ORDERS; +INSERT INTO ORDERS SELECT * FROM PURCHASEORDERS; +ALTER TABLE ORDERS +ADD (po_num_vc NUMBER GENERATED ALWAYS AS + (json_value (DATA, '$.PONumber.number()' + ERROR ON ERROR))); + +ALTER TABLE ORDERS +MODIFY PARTITION BY RANGE (po_num_vc) + (PARTITION p1 VALUES LESS THAN (1000), + PARTITION p2 VALUES LESS THAN (2000), + PARTITION p3 VALUES LESS THAN (3000), + PARTITION p4 VALUES LESS THAN (4000), + PARTITION p5 VALUES LESS THAN (5000), + PARTITION p6 VALUES LESS THAN (6000), + PARTITION p7 VALUES LESS THAN (7000), + PARTITION p8 VALUES LESS THAN (8000), + PARTITION p9 VALUES LESS THAN (9000), + PARTITION p10 VALUES LESS THAN (10000), + PARTITION p11 VALUES LESS THAN (11000) + ); + +-- PARTITION PRUNNING - PARTITION 1 +EXPLAIN PLAN FOR SELECT DATA FROM ORDERS + WHERE JSON_EXISTS(DATA, '$?(@.PONumber == $V1)' + PASSING 200 AS "V1" ); + +SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY()); + +/* +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- +Plan hash value: 3905487950 + +------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop | +------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | 1 | 893 | 72 (0)| 00:00:01 | | | +| 1 | PARTITION RANGE SINGLE| | 1 | 893 | 72 (0)| 00:00:01 | 1 | 1 | +|* 2 | TABLE ACCESS FULL | ORDERS | 1 | 893 | 72 (0)| 00:00:01 | 1 | 1 | +------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + + 2 - filter("ORDERS"."PO_NUM_VC"=200) + +14 rows selected. +*/ +-- partition prunning +EXPLAIN PLAN FOR SELECT DATA FROM ORDERS p + WHERE p.data.PONumber.number() = 10000; + +SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY()); +/* +------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop | +------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | 1 | 893 | 72 (0)| 00:00:01 | | | +| 1 | PARTITION RANGE SINGLE| | 1 | 893 | 72 (0)| 00:00:01 | 11 | 11 | +|* 2 | TABLE ACCESS FULL | ORDERS | 1 | 893 | 72 (0)| 00:00:01 | 11 | 11 | +------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + + 2 - filter("P"."PO_NUM_VC"=10000) + +14 rows selected. +*/ +------------------------------------------ INDEXING -------------------------------------------------------------- +-- Btree index +DROP INDEX po_num_idx; +CREATE UNIQUE INDEX po_num_idx ON ORDERS po + (po.data.PONumber.number()); + +-- Composite Index +DROP INDEX user_cost_ctr_idx; +/*CREATE INDEX user_cost_ctr_idx ON + ORDERS (json_value(data, '$.User' RETURNING VARCHAR2(20)), + json_value(data, '$.CostCenter' RETURNING VARCHAR2(6))); +*/ +-- Composite index, dot notation +CREATE INDEX user_cost_ctr_idx ON + ORDERS po (po.data."User".string(), po.data.CostCenter.string()); + + +-- search index +DROP INDEX po_search_idx; +CREATE SEARCH INDEX po_search_idx ON ORDERS (DATA) + FOR JSON PARAMETERS ('MAINTENANCE AUTO'); + +-- dot notation + +EXPLAIN PLAN FOR SELECT DATA FROM ORDERS p + WHERE p.data.PONumber.number() = 10000; +SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY()); +/* +----------------------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop | +----------------------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | 1 | 893 | 2 (0)| 00:00:01 | | | +| 1 | TABLE ACCESS BY GLOBAL INDEX ROWID| ORDERS | 1 | 893 | 2 (0)| 00:00:01 | ROWID | ROWID | +|* 2 | INDEX UNIQUE SCAN | PO_NUM_IDX | 1 | | 1 (0)| 00:00:01 | | | +----------------------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 2 - access(JSON_VALUE("DATA" /*+ LOB_BY_VALUE */ + -- FORMAT OSON , '$.PONumber.number()' RETURNING + -- NUMBER NULL ON ERROR TYPE(LAX) )=10000) +--Note + -- dynamic statistics used: dynamic sampling (level=AUTO (SYSTEM)) +--19 rows selected. + +-- JSON_EXISTS in Where Clause. PO_SEARCH_IDX chosen +EXPLAIN PLAN FOR SELECT DATA FROM orders + WHERE JSON_EXISTS(DATA, '$?(@.PONumber == $V1)' + PASSING 10000 AS "V1" ); + +SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY()); + + +/* +-------------------------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop | +-------------------------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | 1 | 892 | 6 (0)| 00:00:01 | | | +|* 1 | TABLE ACCESS BY GLOBAL INDEX ROWID| ORDERS | 1 | 892 | 6 (0)| 00:00:01 | ROWID | ROWID | +|* 2 | DOMAIN INDEX | PO_SEARCH_IDX | | | 4 (0)| 00:00:01 | | | +-------------------------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + 1 - filter(JSON_EXISTS2("DATA" /*+ LOB_BY_VALUE */ + -- FORMAT OSON , '$?(@.PONumber == $V1)' PASSING 10000 + -- AS "V1" FALSE ON ERROR TYPE(LAX) )=1 AND JSON_VALUE("ORDERS"."DATA" /*+ LOB_BY_VALUE */ FORMAT OSON , + -- '$.PONumber.number()' RETURNING NUMBER ERROR ON ERROR TYPE(LAX) )=10000) + -- 2 - access("CTXSYS"."CONTAINS"("ORDERS"."DATA" /*+ LOB_BY_VALUE */ + -- ,'(sdata(FNUM_F9A83D1D49108EE786CEBB9017653F0E_PONumber = 10000 ))')>0) + +--18 rows selected. + +EXPLAIN PLAN FOR +SELECT data FROM orders + WHERE json_value(data, '$.User') = 'ABULL' + AND json_value(data, '$.CostCenter') = 'A50'; +SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY()); + +/* +-------------------------------------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop | +-------------------------------------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | 80 | 74640 | 68 (0)| 00:00:01 | | | +| 1 | TABLE ACCESS BY GLOBAL INDEX ROWID BATCHED| ORDERS | 80 | 74640 | 68 (0)| 00:00:01 | ROWID | ROWID | +|* 2 | INDEX RANGE SCAN | USER_COST_CTR_IDX | 85 | | 1 (0)| 00:00:01 | | | +-------------------------------------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + + 2 - access(JSON_VALUE("DATA" /*+ LOB_BY_VALUE */ + -- FORMAT OSON , '$."User".string()' RETURNING VARCHAR2(4000) NULL ON + -- ERROR TYPE(LAX) )='ABULL' AND JSON_VALUE("DATA" /*+ LOB_BY_VALUE */ FORMAT OSON , '$.CostCenter.string()' RETURNING + -- VARCHAR2(4000) NULL ON ERROR TYPE(LAX) )='A50') + + + + +EXPLAIN PLAN FOR +SELECT data FROM orders p + WHERE p.data."User" = 'ABULL' AND p.data.CostCenter = 'A50'; +SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY()); + +/* +-------------------------------------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop | +-------------------------------------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | 80 | 74640 | 71 (0)| 00:00:01 | | | +|* 1 | TABLE ACCESS BY GLOBAL INDEX ROWID BATCHED| ORDERS | 80 | 74640 | 71 (0)| 00:00:01 | ROWID | ROWID | +|* 2 | INDEX RANGE SCAN | USER_COST_CTR_IDX | 85 | | 1 (0)| 00:00:01 | | | +-------------------------------------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + + 1 - filter(JSON_VALUE("P"."DATA" /*+ LOB_BY_VALUE */ + -- FORMAT OSON , '$."User"' RETURNING VARCHAR2(4000) NULL ON +-- ERROR TYPE(STRICT) )='ABULL' AND JSON_VALUE("P"."DATA" /*+ LOB_BY_VALUE */ FORMAT OSON , '$.CostCenter' RETURNING +-- VARCHAR2(4000) NULL ON ERROR TYPE(STRICT) )='A50') +-- 2 - access(JSON_VALUE("DATA" /*+ LOB_BY_VALUE */ FORMAT OSON , '$."User".string()' RETURNING VARCHAR2(4000) NULL ON +-- ERROR TYPE(LAX) )='ABULL' AND JSON_VALUE("DATA" /*+ LOB_BY_VALUE */ FORMAT OSON , '$.CostCenter.string()' RETURNING +-- VARCHAR2(4000) NULL ON ERROR TYPE(LAX) )='A50') + +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- +-- dynamic statistics used: dynamic sampling (level=AUTO (SYSTEM)) + +-- 23 rows selected. + +-------------------------------------------------------------------------------- +---------------------------- PARTIAL INDEX FOR JSON----------------------------- +-------------------------------------------------------------------------------- +drop table COFFEE purge; + +create JSON collection table COFFEE (price_vc NUMBER GENERATED ALWAYS AS (json_value (DATA, '$.price.number()' ERROR ON ERROR))) + PARTITION BY RANGE (price_vc) + (PARTITION p1 VALUES LESS THAN (6), + PARTITION p2 VALUES LESS THAN (10), + PARTITION p3 VALUES LESS THAN (MAXVALUE)); + +insert into COFFEE values (json{ '_id' : 1, 'item' : 'Americanos', 'price' : 7, 'size': 'Short', 'quantity' : 15 }); +insert into COFFEE values (json{ '_id' : 2, 'item' : 'Espresso', 'price' : 5, 'size': 'Short', 'quantity' : 22, +'CoffeeItems' : [{ 'Details' : { 'Description' : 'Italian Espresso', + 'UnitPrice' : 5, + 'Code' : 28995}, + 'Quantity' : 9.0 }, + { 'Details' : { 'Description' : 'Finnish Espresso', + 'UnitPrice' : 5, + 'Code' : 28996}, + 'Quantity' : 13.0 } ] }); +commit work; + +-- Partial index for JSON: +DROP INDEX coffee_price_idx; +CREATE INDEX coffee_price_idx on COFFEE(CASE WHEN JSON_VALUE(data, '$.price') <=5 THEN JSON_VALUE(data, '$.price' RETURNING NUMBER ERROR ON ERROR) ELSE NULL END); + +DROP INDEX coffee_price_vc_idx; +CREATE INDEX coffee_price_vc_idx on COFFEE(CASE WHEN JSON_VALUE(data, '$.price_vc') <=5 THEN JSON_VALUE(data, '$.price_vc' RETURNING NUMBER ERROR ON ERROR) ELSE NULL END); + + +SELECT DATA FROM COFFEE s WHERE s.data.price.number() = 7; +explain plan for SELECT DATA FROM COFFEE s WHERE s.data.price.number() = 7; +select * from dbms_xplan.display(); + + +/* +PLAN_TABLE_OUTPUT +________________________________________________________________________________________________________ +Plan hash value: 853691940 + +----------------------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop | +----------------------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | 1 | 20500 | 274 (0)| 00:00:01 | | | +| 1 | PARTITION RANGE SINGLE | | 1 | 20500 | 274 (0)| 00:00:01 | 2 | 2 | +|* 2 | TABLE ACCESS STORAGE FULL| COFFEE | 1 | 20500 | 274 (0)| 00:00:01 | 2 | 2 | +----------------------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 2 - storage("S"."PRICE_VC"=7) + filter("S"."PRICE_VC"=7) + +Note +----- + - dynamic statistics used: dynamic sampling (level=2) + - automatic DOP: Computed Degree of Parallelism is 1 because of no expensive parallel operation + +20 rows selected. + +*/ + + +-------------------------------------------------------------------------------- +---------------------------- DBMS_SQLDIAG -------------------------------------- +-------------------------------------------------------------------------------- +-- dbms_sqldiag.report_sql + +set feedback on sql_id +SELECT data FROM orders + WHERE json_value(data, '$.User') = 'ABULL' + AND json_value(data, '$.CostCenter') = 'A50'; + +/* +{"_id":"66cd794eca37168420771fea","CostCenter":"A50","PONumber":8358,"Reference":"ABULL-20140509","Requestor":"Alexis Bull","Special Instructions":"Ground","User":"ABULL","ShippingInstructions":{"name":"Alexis Bull","Address":{"city":"South San Francisco","country":"United States of America","state":"CA","street":"200 Sporting Green","zipCode":99236},"Phone":[{"number":"70-555-4236","type":"Office"}]},"LineItems":[{"ItemNumber":1,"Quantity":9,"Part":{"Description":"30th Anniversary of Rock 'N Roll All Star Jam With Bo Diddley","UPCCode":13023010192,"UnitPrice":19.95}},{"ItemNumber":2,"Quantity":4,"Part":{"Description":"All Quiet on the Western Front","UPCCode":25192051029,"UnitPrice":19.95}},{"ItemNumber":3,"Quantity":8,"Part":{"Description":"Malice","UPCCode":27616854780,"UnitPrice":19.95}},{"ItemNumber":4,"Quantity":5,"Part":{"Description":"There's No Business Like Show Business","UPCCode":24543014454,"UnitPrice":19.95}}]} +{"_id":"66cd794eca37168420771f90","CostCenter":"A50","PONumber":8328,"Reference":"ABULL-20140504","Requestor":"Alexis Bull","Special Instructions":"Counter to Counter","User":"ABULL","ShippingInstructions":{"name":"Alexis Bull","Address":{"city":"South San Francisco","country":"United States of America","state":"CA","street":"200 Sporting Green","zipCode":99236},"Phone":[{"number":"25-41-3537","type":"Office"}]},"LineItems":[{"ItemNumber":1,"Quantity":3,"Part":{"Description":"Mark Messier- Leader, Champion and Legend","UPCCode":696306000327,"UnitPrice":19.95}},{"ItemNumber":2,"Quantity":4,"Part":{"Description":"The Prophecy","UPCCode":717951001580,"UnitPrice":19.95}},{"ItemNumber":3,"Quantity":1,"Part":{"Description":"Pokemon: Johto Journeys- Team Green / Japanimat","UPCCode":13023156999,"UnitPrice":27.95}},{"ItemNumber":4,"Quantity":6,"Part":{"Description":"Airport 1975","UPCCode":18713810106,"UnitPrice":19.95}},{"ItemNumber":5,"Quantity":4,"Part":{"Description":"What Dreams May Come","UPCCode":44005827521,"UnitPrice":19.95}}]} +{"_id":"66cd794eca37168420772683","CostCenter":"A50","PONumber":8921,"Reference":"ABULL-20141101","Requestor":"Alexis Bull","Special Instructions":"Counter to Counter","User":"ABULL","ShippingInstructions":{"name":"Alexis Bull","Address":{"city":"South San Francisco","country":"United States of America","state":"CA","street":"200 Sporting Green","zipCode":99236},"Phone":[{"number":"416-555-767","type":"Office"}]},"LineItems":[{"ItemNumber":1,"Quantity":6,"Part":{"Description":"Iron Eagle","UPCCode":43396839694,"UnitPrice":19.95}},{"ItemNumber":2,"Quantity":8,"Part":{"Description":"The Siege","UPCCode":24543010913,"UnitPrice":19.95}},{"ItemNumber":3,"Quantity":2,"Part":{"Description":"Backdraft","UPCCode":25192004124,"UnitPrice":19.95}},{"ItemNumber":4,"Quantity":6,"Part":{"Description":"Truck Turner","UPCCode":27616857910,"UnitPrice":19.95}}]} +{"_id":"66cd794eca37168420772686","CostCenter":"A50","PONumber":8922,"Reference":"ABULL-20141102","Requestor":"Alexis Bull","Special Instructions":"Hand Carry","User":"ABULL","ShippingInstructions":{"name":"Alexis Bull","Address":{"city":"South San Francisco","country":"United States of America","state":"CA","street":"200 Sporting Green","zipCode":99236},"Phone":[{"number":"78-555-8375","type":"Office"}]},"LineItems":[{"ItemNumber":1,"Quantity":1,"Part":{"Description":"The Delta Force","UPCCode":27616852892,"UnitPrice":19.95}},{"ItemNumber":2,"Quantity":1,"Part":{"Description":"Apocalypse Now Redux","UPCCode":97360962949,"UnitPrice":32.95}},{"ItemNumber":3,"Quantity":7,"Part":{"Description":"Doctor Who: The Five Doctors","UPCCode":794051159625,"UnitPrice":27.95}}]} +{"_id":"66cd794eca37168420772689","CostCenter":"A50","PONumber":8923,"Reference":"ABULL-20141107","Requestor":"Alexis Bull","Special Instructions":"Courier","User":"ABULL","ShippingInstructions":{"name":"Alexis Bull","Address":{"city":"South San Francisco","country":"United States of America","state":"CA","street":"200 Sporting Green","zipCode":99236},"Phone":[{"number":"600-555-9900","type":"Office"}]},"LineItems":[{"ItemNumber":1,"Quantity":6,"Part":{"Description":"Fela Live!- Fela Anikulapo-Kuti and the Egypt 80 Band","UPCCode":16351010193,"UnitPrice":19.95}},{"ItemNumber":2,"Quantity":3,"Part":{"Description":"Herbie Mann: Jasil Brass","UPCCode":13023034495,"UnitPrice":19.95}},{"ItemNumber":3,"Quantity":7,"Part":{"Description":"Eraser","UPCCode":85391420224,"UnitPrice":19.95}}]} +{"_id":"66cd794eca3716842077268c","CostCenter":"A50","PONumber":8924,"Reference":"ABULL-20141109","Requestor":"Alexis Bull","Special Instructions":"Courier","User":"ABULL","ShippingInstructions":{"name":"Alexis Bull","Address":{"city":"South San Francisco","country":"United States of America","state":"CA","street":"200 Sporting Green","zipCode":99236},"Phone":[{"number":"728-555-9686","type":"Office"}]},"LineItems":[{"ItemNumber":1,"Quantity":5,"Part":{"Description":"Support Your Local Gunfighter","UPCCode":27616859051,"UnitPrice":19.95}},{"ItemNumber":2,"Quantity":4,"Part":{"Description":"The Four Sided Triangle","UPCCode":13131107593,"UnitPrice":19.95}},{"ItemNumber":3,"Quantity":6,"Part":{"Description":"Devil in a Blue Dress","UPCCode":43396513495,"UnitPrice":19.95}},{"ItemNumber":4,"Quantity":7,"Part":{"Description":"Nothing But Trouble","UPCCode":85391637622,"UnitPrice":19.95}},{"ItemNumber":5,"Quantity":2,"Part":{"Description":"A View to a Kill","UPCCode":27616853967,"UnitPrice":19.95}}]} +{"_id":"66cd794eca3716842077331c","CostCenter":"A50","PONumber":9996,"Reference":"ABULL-20141025","Requestor":"Alexis Bull","Special Instructions":"Courier","User":"ABULL","ShippingInstructions":{"name":"Alexis Bull","Address":{"city":"South San Francisco","country":"United States of America","state":"CA","street":"200 Sporting Green","zipCode":99236},"Phone":[{"number":"796-555-5448","type":"Office"}]},"LineItems":[{"ItemNumber":1,"Quantity":5,"Part":{"Description":"Ancient Secrets of Bible: David / Samson","UPCCode":56775056797,"UnitPrice":19.95}},{"ItemNumber":2,"Quantity":9,"Part":{"Description":"Stomp Out Loud","UPCCode":26359148422,"UnitPrice":19.95}},{"ItemNumber":3,"Quantity":4,"Part":{"Description":"The Mosquito Coast","UPCCode":85393622121,"UnitPrice":19.95}}]} +{"_id":"66cd794eca3716842077316c","CostCenter":"A50","PONumber":9852,"Reference":"ABULL-20141001","Requestor":"Alexis Bull","Special Instructions":"Expidite","User":"ABULL","ShippingInstructions":{"name":"Alexis Bull","Address":{"city":"South San Francisco","country":"United States of America","state":"CA","street":"200 Sporting Green","zipCode":99236},"Phone":[{"number":"604-555-550","type":"Office"}]},"LineItems":[{"ItemNumber":1,"Quantity":2,"Part":{"Description":"I Spy: Blackout","UPCCode":14381983425,"UnitPrice":19.95}},{"ItemNumber":2,"Quantity":6,"Part":{"Description":"The Prophecy","UPCCode":717951001580,"UnitPrice":19.95}},{"ItemNumber":3,"Quantity":4,"Part":{"Description":"Kingpin","UPCCode":27616627520,"UnitPrice":19.95}}]} +{"_id":"66cd794eca3716842077316f","CostCenter":"A50","PONumber":9853,"Reference":"ABULL-20141001","Requestor":"Alexis Bull","Special Instructions":"Expidite","User":"ABULL","ShippingInstructions":{"name":"Alexis Bull","Address":{"city":"South San Francisco","country":"United States of America","state":"CA","street":"200 Sporting Green","zipCode":99236},"Phone":[{"number":"670-555-5384","type":"Office"}]},"LineItems":[{"ItemNumber":1,"Quantity":3,"Part":{"Description":"Switch","UPCCode":26359055027,"UnitPrice":19.95}},{"ItemNumber":2,"Quantity":2,"Part":{"Description":"Grosse Point & High Fidelity","UPCCode":786936161328,"UnitPrice":32.95}},{"ItemNumber":3,"Quantity":5,"Part":{"Description":"Mysteries & Myths Of 20th Century 3","UPCCode":56775042998,"UnitPrice":19.95}}]} +{"_id":"66cd794eca37168420773172","CostCenter":"A50","PONumber":9854,"Reference":"ABULL-20141006","Requestor":"Alexis Bull","Special Instructions":"Surface Mail","User":"ABULL","ShippingInstructions":{"name":"Alexis Bull","Address":{"city":"South San Francisco","country":"United States of America","state":"CA","street":"200 Sporting Green","zipCode":99236},"Phone":[{"number":"284-555-8087","type":"Office"}]},"LineItems":[{"ItemNumber":1,"Quantity":1,"Part":{"Description":"Jackie Chan's First Strike","UPCCode":794043466922,"UnitPrice":19.95}},{"ItemNumber":2,"Quantity":5,"Part":{"Description":"Pecker","UPCCode":794043473128,"UnitPrice":19.95}},{"ItemNumber":3,"Quantity":1,"Part":{"Description":"Plenty","UPCCode":17153111903,"UnitPrice":19.95}},{"ItemNumber":4,"Quantity":1,"Part":{"Description":"Deathtrap","UPCCode":85391125624,"UnitPrice":19.95}}]} + +85 rows selected. + + + +SQL_ID: 8zqk5j2jzta0r +*/ +-- insert the report into a CLOB variable +set feedback on +var report clob; +exec :report := dbms_sqldiag.report_sql('8zqk5j2jzta0r'); +--spool the file +set trimspool on +set TRIM on + set pagesize 0 +set pagesize 0 +set linesize 32767 +set long 1000000 +set longchunksize 1000000 + +spool diagsql1.html +select :report report FROM dual; +spool off + diff --git a/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/06.json-dataguide.sql b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/06.json-dataguide.sql new file mode 100644 index 000000000..9241cba73 --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/06.json-dataguide.sql @@ -0,0 +1,150 @@ + +-- Relational Views using JSON_DATAGUIDE +------------------------------------------------------------------------------------------------------- +-- Creating a Relational view from PURCHASEORDERS using JSON_DATAGUIDE +------------------------------------------------------------------------------------------------------- +DECLARE + dg CLOB; + BEGIN + SELECT JSON_DATAGUIDE(DATA, + DBMS_JSON.FORMAT_HIERARCHICAL, + DBMS_JSON.PRETTY) + INTO dg + FROM PURCHASEORDERS; + DBMS_JSON.create_view('PURCHASEORDERS_DG_V', + 'PURCHASEORDERS', + 'DATA', + dg); + END; +/ + + +-- Generated View- + +CREATE OR REPLACE VIEW "PURCHASEORDERS_DG_V" ("_id", "User", "PONumber", "Reference", "Requestor", "CostCenter", "AllowPartialShipment", "name", "Address", "city", "state", "county", "street", "country", "zipCode", "postcode", "province", "Special Instructions", "UPCCode", "UnitPrice", "Description", "Quantity", "ItemNumber", "type", "number") AS + SELECT JT."_id",JT."User",JT."PONumber",JT."Reference",JT."Requestor",JT."CostCenter",JT."AllowPartialShipment",JT."name",JT."Address",JT."city",JT."state",JT."county",JT."street",JT."country",JT."zipCode",JT."postcode",JT."province",JT."Special Instructions",JT."UPCCode",JT."UnitPrice",JT."Description",JT."Quantity",JT."ItemNumber",JT."type",JT."number" +FROM "PURCHASEORDERS" RT, +JSON_TABLE("DATA", '$[*]' COLUMNS + "_id" raw(12) path '$._id', + "User" varchar2(8) path '$.User', + "PONumber" number path '$.PONumber', + NESTED PATH '$.LineItems[*]' COLUMNS ( + "UPCCode" number path '$.Part.UPCCode', + "UnitPrice" binary_double path '$.Part.UnitPrice', + "Description" json path '$.Part.Description', + "Quantity" number path '$.Quantity', + "ItemNumber" number path '$.ItemNumber'), + "Reference" varchar2(32) path '$.Reference', + "Requestor" varchar2(32) path '$.Requestor', + "CostCenter" varchar2(4) path '$.CostCenter', + "AllowPartialShipment" varchar2(4) path '$.AllowPartialShipment', + "name" varchar2(32) path '$.ShippingInstructions.name', + NESTED PATH '$.ShippingInstructions.Phone[*]' COLUMNS ( + "type" varchar2(8) path '$.type', + "number" varchar2(16) path '$.number'), + "Address" varchar2(1) path '$.ShippingInstructions.Address', + "city" varchar2(32) path '$.ShippingInstructions.Address.city', + "state" varchar2(2) path '$.ShippingInstructions.Address.state', + "county" varchar2(8) path '$.ShippingInstructions.Address.county', + "street" varchar2(64) path '$.ShippingInstructions.Address.street', + "country" varchar2(32) path '$.ShippingInstructions.Address.country', + "zipCode" number path '$.ShippingInstructions.Address.zipCode', + "postcode" json path '$.ShippingInstructions.Address.postcode', + "province" varchar2(2) path '$.ShippingInstructions.Address.province', + "Special Instructions" json path '$."Special Instructions"')JT; + +------------------------------------------------------------------------------------------------------- +DESCRIBE PURCHASEORDERS_DG_V +; +/* + Name Null? Type + -------------------- -------- --------------------------- + DATE_LOADED TIMESTAMP(6) WITH TIME ZONE + ID NOT NULL RAW(16) + User VARCHAR2(8) + PONumber NUMBER + UPCCode NUMBER + UnitPrice NUMBER + Description VARCHAR2(32) + Quantity NUMBER + ItemNumber NUMBER + Reference VARCHAR2(16) + Requestor VARCHAR2(16) + CostCenter VARCHAR2(4) + AllowPartialShipment VARCHAR2(4) + name VARCHAR2(16) + Phone VARCHAR2(16) + type VARCHAR2(8) + number VARCHAR2(16) + city VARCHAR2(32) + state VARCHAR2(2) + street VARCHAR2(32) + country VARCHAR2(32) + zipCode NUMBER + Special Instructions VARCHAR2(8) +*/ + + + SELECT "PONumber" + ,"Requestor" + , "Special Instructions" + , "zipCode" + , "UPCCode" + , "ItemNumber" + , "Quantity" + ,"Description" + FROM + PURCHASEORDERS_DG_V + WHERE "PONumber" =7; + +/* + PONumber Requestor Special Instructions zipCode UPCCode ItemNumber Quantity Description +___________ ______________ _______________________ __________ ______________ _____________ ___________ ___________________________________ + 7 Vance Jones "Hand Carry" 99236 13131111798 1 3 "The Kentucky Fried Movie" + 7 Vance Jones "Hand Carry" 99236 43396086494 2 4 "The Loves of Carmen" + 7 Vance Jones "Hand Carry" 99236 24543016403 3 7 "Two Girls And A Guy" + 7 Vance Jones "Hand Carry" 99236 25192033926 4 4 "Fear and Loathing in Las Vegas" + 7 Vance Jones "Hand Carry" 99236 +*/ + + +------------------------------------------------------------------------------------------------------- +-- Creating a View That Projects Scalar Fields Targeted By a Path Expression +------------------------------------------------------------------------------------------------------- +-- Enabling Persistent Support for a JSON Data Guide But Not For Search +CREATE SEARCH INDEX po_dg_only_idx + ON PURCHASEORDERS (data) FOR JSON + PARAMETERS ('DATAGUIDE ON SEARCH_ON NONE'); + + +EXEC DBMS_JSON.create_view_on_path('LINEITEMS_C','PURCHASEORDERS','DATA','$.LineItems.Part'); + +/* +SQL> DESC LINEITEMS_C; + +Name Null? Type +____________________________ ________ ________________ +DATA$_id RAW(12 BYTE) +DATA$User VARCHAR2(8) +DATA$PONumber NUMBER +DATA$Reference VARCHAR2(32) +DATA$Requestor VARCHAR2(32) +DATA$CostCenter VARCHAR2(4) +DATA$AllowPartialShipment VARCHAR2(4) +DATA$name VARCHAR2(32) +DATA$Address VARCHAR2(1) +DATA$city VARCHAR2(32) +DATA$state VARCHAR2(2) +DATA$county VARCHAR2(8) +DATA$street VARCHAR2(64) +DATA$country VARCHAR2(32) +DATA$zipCode NUMBER +DATA$postcode VARCHAR2(8) +DATA$province VARCHAR2(2) +DATA$SpecialInstructions VARCHAR2(32) +DATA$UPCCode NUMBER +DATA$UnitPrice BINARY_DOUBLE +DATA$Description VARCHAR2(128) +*/ + + \ No newline at end of file diff --git a/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/08.json-schema.sql b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/08.json-schema.sql new file mode 100644 index 000000000..391ec68c4 --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/08.json-schema.sql @@ -0,0 +1,260 @@ +------------------------------------------------------------------------------------ +-- JSON schemas can be used to validate the strctucture and type of JSON documents +-- Use cases: +---- 1.JSON Schema validation +---- 2.Generating JSON schemas +--------------------------------------------------------------------------------------- + + +-- JSON Schema Validation without constraint +SELECT JSON_SERIALIZE(data pretty) FROM purchaseorders + WHERE data IS JSON VALIDATE + '{"type" : "object", + "properties" : {"PONumber": {"type" : "number", + "minimum" : 10000}}}'; +/* +*/ +-- Generating JSON SCHEMAS with data guide: +-- Data guide creates a JSON schema from an existing set of JSON documents +-- FLAT data guide +SET LONG 1000000 PAGESIZE 1000 +SELECT JSON_DATAGUIDE(data,DBMS_JSON.format_flat) +FROM PURCHASEORDERS; +/* +[{"o:path":"$","type":"object","o:length":1},{"o:path":"$._id","type":"id","o:le +ngth":12},{"o:path":"$.User","type":"string","o:length":8},{"o:path":"$.PONumber +","type":"number","o:length":4},{"o:path":"$.LineItems","type":"array","o:length +":1},{"o:path":"$.LineItems.Part","type":"object","o:length":1},{"o:path":"$.Lin +eItems.Part.UPCCode","type":"number","o:length":8},{"o:path":"$.LineItems.Part.U +nitPrice","type":"double","o:length":8},{"o:path":"$.LineItems.Part.Description" +,"type":"json(scalar)","o:length":128},{"o:path":"$.LineItems.Quantity","type":" +number","o:length":2},{"o:path":"$.LineItems.ItemNumber","type":"number","o:leng +th":2},{"o:path":"$.Reference","type":"string","o:length":32},{"o:path":"$.Reque +stor","type":"string","o:length":32},{"o:path":"$.CostCenter","type":"string","o +:length":4},{"o:path":"$.AllowPartialShipment","type":"boolean","o:length":4},{" +o:path":"$.ShippingInstructions","type":"object","o:length":1},{"o:path":"$.Ship +pingInstructions.name","type":"string","o:length":32},{"o:path":"$.ShippingInstr +uctions.Phone","type":"array","o:length":1},{"o:path":"$.ShippingInstructions.Ph +one.type","type":"string","o:length":8},{"o:path":"$.ShippingInstructions.Phone. +number","type":"string","o:length":16},{"o:path":"$.ShippingInstructions.Address +","type":"string","o:length":1},{"o:path":"$.ShippingInstructions.Address","type +":"object","o:length":1},{"o:path":"$.ShippingInstructions.Address.city","type": +"string","o:length":32},{"o:path":"$.ShippingInstructions.Address.state","type": +"string","o:length":2},{"o:path":"$.ShippingInstructions.Address.county","type": +"string","o:length":8},{"o:path":"$.ShippingInstructions.Address.street","type": +"string","o:length":64},{"o:path":"$.ShippingInstructions.Address.country","type +":"string","o:length":32},{"o:path":"$.ShippingInstructions.Address.zipCode","ty +pe":"number","o:length":4},{"o:path":"$.ShippingInstructions.Address.postcode"," +type":"json(scalar)","o:length":8},{"o:path":"$.ShippingInstructions.Address.pro + vince","type":"string","o:length":2},{"o:path":"$.\"Special Instructions\"","typ + e":"json(scalar)","o:length":32}] + + +*/ + +-- Flat format and pretty. +DBMS_JSON.format_hierarchical +-- Hierarchical data guide +SELECT JSON_DATAGUIDE(data, DBMS_JSON.format_hierarchical) +FROM PURCHASEORDERS; + +/* +{"type":"object","o:length":1,"properties":{"_id":{"type":"id","o:length":12,"o: +preferred_column_name":"_id"},"User":{"type":"string","o:length":8,"o:preferred_ +column_name":"User"},"PONumber":{"type":"number","o:length":4,"o:preferred_colum +n_name":"PONumber"},"LineItems":{"type":"array","o:length":1,"o:preferred_column +_name":"LineItems","items":{"properties":{"Part":{"type":"object","o:length":1," +o:preferred_column_name":"Part","properties":{"UPCCode":{"type":"number","o:leng +th":8,"o:preferred_column_name":"UPCCode"},"UnitPrice":{"type":"double","o:lengt +h":8,"o:preferred_column_name":"UnitPrice"},"Description":{"type":"json(scalar)" +,"o:length":128,"o:preferred_column_name":"Description"}}},"Quantity":{"type":"n +umber","o:length":2,"o:preferred_column_name":"Quantity"},"ItemNumber":{"type":" +number","o:length":2,"o:preferred_column_name":"ItemNumber"}}}},"Reference":{"ty +pe":"string","o:length":32,"o:preferred_column_name":"Reference"},"Requestor":{" +type":"string","o:length":32,"o:preferred_column_name":"Requestor"},"CostCenter" +:{"type":"string","o:length":4,"o:preferred_column_name":"CostCenter"},"AllowPar +tialShipment":{"type":"boolean","o:length":4,"o:preferred_column_name":"AllowPar +tialShipment"},"ShippingInstructions":{"type":"object","o:length":1,"o:preferred +_column_name":"ShippingInstructions","properties":{"name":{"type":"string","o:le +ngth":32,"o:preferred_column_name":"name"},"Phone":{"type":"array","o:length":1, +"o:preferred_column_name":"Phone","items":{"properties":{"type":{"type":"string" +,"o:length":8,"o:preferred_column_name":"type"},"number":{"type":"string","o:len +gth":16,"o:preferred_column_name":"number"}}}},"Address":{"oneOf":[{"type":"stri +ng","o:length":1,"o:preferred_column_name":"Address"},{"type":"object","o:length +":1,"o:preferred_column_name":"Address","properties":{"city":{"type":"string","o +:length":32,"o:preferred_column_name":"city"},"state":{"type":"string","o:length +":2,"o:preferred_column_name":"state"},"county":{"type":"string","o:length":8,"o +:preferred_column_name":"county"},"street":{"type":"string","o:length":64,"o:pre +ferred_column_name":"street"},"country":{"type":"string","o:length":32,"o:prefer +red_column_name":"country"},"zipCode":{"type":"number","o:length":4,"o:preferred +_column_name":"zipCode"},"postcode":{"type":"json(scalar)","o:length":8,"o:prefe +rred_column_name":"postcode"},"province":{"type":"string","o:length":2,"o:prefer +red_column_name":"province"}}}]}}},"Special Instructions":{"type":"json(scalar)" +,"o:length":32,"o:preferred_column_name":"Special Instructions"}}} +*/ + +-- Generating JSON SCHEMAS with DBMS_JON_SCHEMA.describe +-- JSON Collection +SELECT JSON_SERALIZE( + DBMS_JSON_SCHEMA.describe( + object_name =>'PURCHASEORDERS') + ,owner_name => 'SALES_HISTORY'); +/* +{ + "title" : "PURCHASEORDERS", + "dbObject" : "SALES_HISTORY.PURCHASEORDERS", + "type" : "object", + "dbObjectType" : "table", + "properties" : + { + "DATA" : + { + "anyOf" : + [ + { + "type" : "object", + "extendedType" : "object" + } + ] + } + }, + "dbPrimaryKey" : + [ + "RESID" + ] +} +*/ + +-- Relational table +select JSON_SERIALIZE(DBMS_JSON_SCHEMA.describe( + object_name =>'SALES' + ,owner_name => 'SALES_HISTORY')pretty); + +/* +{ + "title" : "SALES", + "dbObject" : "SALES_HISTORY.SALES", + "description" : "facts table, without a primary key; all rows are uniquely identified by the combination of all foreign k +eys", + "type" : "object", + "dbObjectType" : "table", + "properties" : + { + "PROD_ID" : + { + "description" : "FK to the products dimension table", + "type" : "integer", + "extendedType" : "integer", + "sqlPrecision" : 6 + }, + .......................................... + */ + +-- Duality view +select JSON_SERIALIZE(DBMS_JSON_SCHEMA.describe( + object_name =>'PRODUCTS_DV' + ,owner_name => 'SALES_HISTORY')pretty); + +/* +{ + "title" : "PRODUCTS_DV", + "dbObject" : "SALES_HISTORY.PRODUCTS_DV", + "dbObjectType" : "dualityView", + "dbObjectProperties" : + [ + "insert", + "update", + "check" + ], + "type" : "object", + "properties" : + { + "_id" : + { + "type" : "number", + "extendedType" : "number", + "dbFieldProperties" : + [ + "check" + ] + }, +*/ + + + + + +-- JSON Document validation report +-- PURCHASEORDERS JSON Collection +SET SERVEROUTPUT ON +DECLARE +j_doc JSON; +j_schema JSON; + r JSON; +result VARCHAR2(2000); + +BEGIN + SELECT DBMS_JSON_SCHEMA.describe( + object_name =>'PURCHASEORDERS' + ,owner_name => 'SALES_HISTORY') into j_schema; + SELECT po.DATA into j_doc FROM PURCHASEORDERS po + WHERE po.DATA.PONumber=1; + SELECT DBMS_JSON_SCHEMA.VALIDATE_REPORT (j_doc, j_schema) into r; + SELECT JSON_SERIALIZE(r pretty) INTO result; + DBMS_OUTPUT.PUT_LINE('Result is' || result); +END; +/ +/* +Result is{ + "valid" : true, + "errors" : + [ + ] +} +*/ +-- JSON Document validation report +-- SALES Collection + +SET SERVEROUTPUT ON +DECLARE +j_doc JSON; +j_schema JSON; + r JSON; +result VARCHAR2(2000); + +BEGIN + SELECT DBMS_JSON_SCHEMA.describe( + object_name =>'SALES' + ,owner_name => 'SALES_HISTORY') into j_schema; + SELECT JSON {*} into j_doc FROM SALES WHERE rownum <2; + SELECT DBMS_JSON_SCHEMA.VALIDATE_REPORT (j_doc, j_schema) into r; + SELECT JSON_SERIALIZE(r pretty) INTO result; + DBMS_OUTPUT.PUT_LINE('Result is' || result); +END; +/* +Result is{ + "valid" : false, + "errors" : + [ + { + "schemaPath" : "$", + "instancePath" : "$", + "code" : "JZN-00501", + "error" : "JSON schema validation failed" + }, + { + "schemaPath" : "$.properties", + "instancePath" : "$", + "code" : "JZN-00514", + "error" : "invalid properties: 'TIME_ID'" + }, + { + "schemaPath" : "$.properties.TIME_ID.type", + "instancePath" : "$.TIME_ID", + "code" : "JZN-00503", + "error" : "invalid type found, actual: , expected: string" + } + ] +} +*/ + \ No newline at end of file diff --git a/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/10.ajd-user-roles.sql b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/10.ajd-user-roles.sql new file mode 100644 index 000000000..8ced71831 --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/10.ajd-user-roles.sql @@ -0,0 +1,122 @@ + +-------------------------------------------------------------------------------------------------- +-- In Autonomous Database the predefined administrative user is ADMIN. This account has privileges +-- to manage users and to manage the database. +-- Admin roles and prvileges can be queried from ROLE_SYS_PRIVS and DBA_SYS_PRIVS views +-------------------------------------------------------------------------------------------------- + +SELECT * FROM ROLE_SYS_PRIVS; + + +SELECT PRIVILEGE FROM DBA_SYS_PRIVS WHERE GRANTEE = 'ADMIN' ORDER BY 1; + + + +------------------------------------------------------------------------------------------------ +-- CREATING and ordinary (app dev) user: +-- Oracle Database API for MongoDB relies on Oracle Database users, privileges, and roles. +-- The minimum Oracle Database roles required to use the API are CONNECT, RESOURCE, and SODA_APP. +------------------------------------------------------------------------------------------------- +CREATE USER JSONDEV IDENTIFIED BY DB23ee###1234; +-- ADD ROLES +GRANT CONNECT, RESOURCE, SODA_APP TO JSONDEV; +-- QUOTA +ALTER USER JSONDEV QUOTA UNLIMITED ON DATA; +-- Enabling ORDS +BEGIN + ords_admin.enable_schema( + p_enabled => TRUE, + p_schema => 'devuser', + p_url_mapping_pattern => 'devuser' + ); + commit; +END; +/ + + +-- JSONDEV roles and privileges + +SELECT * FROM USER_ROLE_PRIVS; +/* +USERNAME GRANTED_ROLE ADMIN_OPTION DELEGATE_OPTION DEFAULT_ROLE OS_GRANTED COMMON INHERITED +___________ _______________ _______________ __________________ _______________ _____________ _________ ____________ +JSONDEV CONNECT NO NO YES NO NO NO +JSONDEV RESOURCE NO NO YES NO NO NO +JSONDEV SODA_APP NO NO YES NO NO NO +*/ + + + SELECT * FROM ROLE_SYS_PRIVS; +/* +ROLE PRIVILEGE ADMIN_OPTION COMMON INHERITED +___________ _____________________________ _______________ _________ ____________ +RESOURCE CREATE PROPERTY GRAPH NO YES YES +RESOURCE CREATE ANALYTIC VIEW NO YES YES +RESOURCE CREATE HIERARCHY NO YES YES +RESOURCE CREATE ATTRIBUTE DIMENSION NO YES YES +CONNECT SET CONTAINER NO YES YES +RESOURCE CREATE INDEXTYPE NO YES YES +RESOURCE CREATE OPERATOR NO YES YES +RESOURCE CREATE TYPE NO YES YES +RESOURCE CREATE MATERIALIZED VIEW NO YES YES +RESOURCE CREATE TRIGGER NO YES YES +RESOURCE CREATE PROCEDURE NO YES YES +RESOURCE CREATE SEQUENCE NO YES YES +RESOURCE CREATE VIEW NO YES YES +RESOURCE CREATE SYNONYM NO YES YES +RESOURCE CREATE CLUSTER NO YES YES +RESOURCE CREATE TABLE NO YES YES +CONNECT CREATE SESSION NO YES YES + +17 rows selected. +*/ + + +------------------------------------------------------------------------------------------------ +-- An ORACLE user can be switched to read only mode by ADMIN +------------------------------------------------------------------------------------------------- + +ALTER USER JSONDEV READ ONLY; + +----------------------------------------------------------------------------------------------------- +-- Creating an Administrative user: +-- Administrative users can create new users (database schemas) +-- Oracle database roles CONNECT, RESOURCE, SODA_APP, CREATE USER, ALTER USER, DROP USER. +-- Oracle recommends not allow production applications to make use of an administrative user. +-- Applications should instead connect as ordinary users, with a minimum set of privileges +------------------------------------------------------------------------------------------------------ + +CREATE USER JSONADM IDENTIFIED BY DB23ee###1234; +-- ADD ROLES +GRANT CONNECT, RESOURCE, SODA_APP TO JSONADM; +GRANT CREATE USER, ALTER USER, DROP USER to JSONADM; +-- QUOTA +ALTER USER JSONDEV QUOTA UNLIMITED ON DATA; +-- Enabling ORDS +BEGIN + ords_admin.enable_schema( + p_enabled => TRUE, + p_schema => 'jsonadm', + p_url_mapping_pattern => 'jsonadm' + ); + commit; +END; +/ + +CREATE USER JSONDEV1 IDENTIFIED BY DB23ee###1234; +/* +User JSONDEV1 created. +*/ + +DROP USER JSONDEV1; +/* +User JSONDEV1 dropped. +*/ + + +---------------------------------------------------------------------------------------------------------------- +---------------- Grants required to load JSON files from Object Storage ---------------------------------- +---------------------------------------------------------------------------------------------------------------- + + GRANT EXECUTE on DBMS_CLOUD to JSONDEV + GRANT READ,WRITE on DIRECTORY data_pump_dir to JSONDEV \ No newline at end of file diff --git a/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/11.load-json-coll.sql b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/11.load-json-coll.sql new file mode 100644 index 000000000..c3f849d14 --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/11.load-json-coll.sql @@ -0,0 +1,86 @@ +------------------------------------------------------------------------------------------------------- +---------------- 1. Load JSON Collection (File System) ------------------------------------------------ +------------------------------------------------------------------------------------------------------- + +--Create DIRECTORY(as system) +CREATE OR REPLACE DIRECTORY order_entry_dir as '/home/oracle'; +CREATE OR REPLACE DIRECTORY JSON_LOADER_OUTPUT as '/home/oracle'; +GRAN READ, WRITE ANY DIRECTORY to '%1' + + + +-- LOAD OPTION 1: CREATE External table using dmp file + +DROP TABLE json_dump_file_contents; +CREATE TABLE json_dump_file_contents (json_document JSON) + ORGANIZATION EXTERNAL + (TYPE ORACLE_LOADER DEFAULT DIRECTORY order_entry_dir + ACCESS PARAMETERS + (RECORDS DELIMITED BY 0x'0A' + DISABLE_DIRECTORY_LINK_CHECK + BADFILE JSON_LOADER_OUTPUT: 'JSON_DUMPFILE_CONTENTS.bad' + LOGFILE JSON_LOADER_OUTPUT: 'JSON_DUMPFILE_CONTENTS.log' + FIELDS (json_document CHAR(5000))) + LOCATION (order_entry_dir:'PURCHASEORDERS.dmp')) + PARALLEL + REJECT LIMIT UNLIMITED; + + +-- LOAD OPTION 2: CREATE External table using ORACLE_BIGDATA driver +DROP TABLE json_file_contents CASCADE CONSTRAINTS; +CREATE TABLE json_file_contents (DATA JSON) + ORGANIZATION EXTERNAL + (TYPE ORACLE_BIGDATA + ACCESS PARAMETERS (com.oracle.bigDATA.fileformat = jsondoc) + LOCATION (order_entry_dir:'PURCHASEORDERS.dmp')) + PARALLEL + REJECT LIMIT UNLIMITED; + + +------------------------------------------------------------------------------------------------------- +-- Creating a Table With a JSON Column for JSON DATA +------------------------------------------------------------------------------------------------------- +DROP TABLE J_PURCHASEORDER CASCADE CONSTRAINTS; +CREATE TABLE J_PURCHASEORDER + (id VARCHAR2 (32) NOT NULL PRIMARY KEY, + date_loaded TIMESTAMP (6) WITH TIME ZONE, + pdmpo_document JSON); + +-- populating J_PURCHASEORDER + +INSERT INTO J_PURCHASEORDER, po_document) + SELECT SYS_GUID(), SYSTIMESTAMP,json_document + FROM json_dump_file_contents; + INSERT INTO PURCHASEORDERS SELECT * FROM json_dump_file_contents; + + + -- Copying JSON DATA FROM an External Table To a JSON Collection Table. ( 23ai ) + +DROP TABLE PURCHASEORDERS CASCADE CONSTRAINTS; +CREATE JSON COLLECTION TABLE PURCHASEORDERS; +INSERT INTO PURCHASEORDERS SELECT * FROM json_file_contents; + +--checking JSON dictionary views + +SELECT * FROM USER_JSON_COLUMNS; +/* +TABLE_NAME OBJECT_TYPE COLUMN_NAME FORMAT DATA_TYPE +_________________ ______________ ______________ _________ ____________ +PURCHASEORDERS TABLE DATA OSON JSON */ + +------------------------------------------------------------------------------------------------------- +-- LOAD OPTION 3 : Load DATA using DBMS_CLOUD +------------------------------------------------------------------------------------------------------- +-- upload PurchaseOrder.dmp to object store +-- e.g. the object uri is +-- https://objectstorage.eu-frankfurt-1.oraclecloud.com/n/fro8fl9kuqli/b/bucket-for-ajd-data/o/PurchaseOrders.dmp + +EXEC DBMS_CLOUD.create_credential(credential_name => 'ajd_cred', username => 'SALES_HISTORY', password => '&1'); + +BEGIN +DBMS_CLOUD.copy_collection(collection_name => 'PURCHASEORDERS' +, credential_name => 'ajd_cred' +, file_uri_list => 'https://objectstorage.eu-frankfurt-1.oraclecloud.com/p/Nxp67PGb4W2anSsgURMhXmGptTlswzZFbugXkTu4Wy0fDWCbuxvXTvNiyXssrurA/n/fro8fl9kuqli/b/bucket-for-ajd-data/o/PurchaseOrders.dmp' +, format => json_object('recorddelimiter' value '''\n''')); +END; +/ diff --git a/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/README.md b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/README.md index 8b1378917..74f5ab141 100644 --- a/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/README.md +++ b/data-platform/autonomous-database/autonomous-json/oracle-api-for-mongodb-demos/sql/po/files/README.md @@ -1 +1,19 @@ +# oracle-json sample NodeJS scripts presenting different features of MongoDB API and Oracle JSON Database +### 02_basic_demo.js +This script contains examples describin Oracle API for MongoDB support for basic native MongoDB statements, like insert, insertMany, update, and find +### 03_expr.js +This script contains an example of using $sql operator allowing for executing SQL statements against an Oracle API for MongoDB instance and how it can be used as a replacement for $expr native MongoDB operator +### 04_mongo_views.js +This script contains an example proving that MongoDB views are fully supported by Oracle API for MongoDB, including their creation using native MongoDB commands +### 05_oracle_views.js +This script contains examples of using Oracle JSON Collection Views and JSON Duality Views in queries expressed by using native MongoDB commands. +examples cover creation, data loading (JSON Duality Views), querying as well as execution plans generation. +### 06_partial_indexes.js +This script contains example comparing native MongoDB partial indexes (not supported in exactly the same form by Oracle API for MongoDB) and Oracle function-based indexes, which can be used as a partial indexes replacements, but also offer full functionality of building indexing expressions, which are not limited to indexing only a part of the data. +### 07_ps_indexes.js +This script contains examples of using Oracle-specific Path-Subsetting indexes to increase the performance of MongoDB native commands. Examples cover creation such indexes by executing native MongoDB commands ($sql operator) as well as querying data and generating execution plans, which use such indexes +### 08_mv_indexes.js +This is the second script presenting another type of Oracle-specific indexes - Multivalue Indexes with examples of their creation and usage in MongoDB native queries, including displaying execution plans +### 09_transactions.js +This script presents full ACID transactions support provided by Oracle Database and Oracle API for MongoDB to MongoDB native applications: no limitations for size and time and availability even in case of a single-node/non-cluster/non-sharding architecture