|
| 1 | +-- Copyright (c) 2024 Oracle and/or its affiliates. |
| 2 | +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ |
| 3 | + |
| 4 | +/* Apply AI SQL function to your data to summarize information, make recommendations and more */ |
| 5 | + |
| 6 | +/* PREREQUISITES |
| 7 | + Install the sample schema using script |
| 8 | + @data-create-sample-schema.sql |
| 9 | +*/ |
| 10 | + |
| 11 | +/* Working with JSON in Autonomous Database |
| 12 | +We can query relational data as JSON and also create JSON Collection tables. Different ways to work with JSON, |
| 13 | +flexiblity to work with JSON, and leverage relational tables by using JSON Duality views providing the best of both worlds. |
| 14 | +Let's look at a couple of ways of creating JSON collection tables, JSON Duality Views and querying JSON data. |
| 15 | +*/ |
| 16 | +-- JSON Collection |
| 17 | +create JSON COLLECTION TABLE MOVIE_BUDGET; |
| 18 | + |
| 19 | +insert into movie_budget values ('{"movie_id": 1,"movie_title":"Avatar","movie_year": 2009, |
| 20 | +"sku":"LYG56160","runtime": 162,"cast":["Sam Worthington","Zoe Saldana"], |
| 21 | +"studio":["20th Century Studios","Lightstorm Entertainment"]}' ); |
| 22 | +insert into movie_budget values ('{"movie_id": 2,"movie_title":"Ghostbusters II","movie_year": 1989, |
| 23 | +"sku":"FWT19789","runtime": 104,"cast":["Bill Murray","Sigourney Weaver"], |
| 24 | +"genre":["Fantasy","Sci-Fi","Thriller","Comedy"]}' ); |
| 25 | +commit; |
| 26 | +--see the JSON collection that has been created along with the ability to query it |
| 27 | +select * from movie_budget; |
| 28 | +--Let's add budget information to the movies |
| 29 | +update movie_budget set data= JSON_TRANSFORM(data, set '$.budgetUnit' = 'Million USD', set '$.budget'=1000000); |
| 30 | +commit; |
| 31 | +select json_value(data, '$.movie_id') movie_id,json_value(data,'$.budget') budget from movie_budget; |
| 32 | +--Change the budget for one of the movies |
| 33 | +update movie_budget set data= JSON_TRANSFORM(data, set '$.budget'=(json_value(data,'$.budget') * 2)) |
| 34 | +where JSON_VALUE(data,'$.movie_id')=2; |
| 35 | +commit; |
| 36 | +select json_value(data, '$.movie_id') movie_id,json_value(data,'$.budget') budget from movie_budget; |
| 37 | + |
| 38 | +--JSON Duality |
| 39 | +/* We can work with our relational tables as JSON Documents by creating a JSON Duality View. |
| 40 | +Inserts, updates and deletes can be performed directly against the JSON Duality View and the changes happen on the underlying relational tables. |
| 41 | +This means that the JSON documents for these views will be updated without having to maintain each document, and the data is stored relationally |
| 42 | +avoiding duplication. |
| 43 | +*/ |
| 44 | +--Simple JSON view on one table |
| 45 | + |
| 46 | +--We need primary keys on the tables that are part of the views |
| 47 | +CREATE OR REPLACE JSON RELATIONAL DUALITY VIEW customer_dv AS |
| 48 | +customer @insert @update @delete |
| 49 | +{ |
| 50 | + _id : cust_id, |
| 51 | + FirstName : first_name, |
| 52 | + LastName : last_name, |
| 53 | + age : age, |
| 54 | + Email : email, |
| 55 | + street_address : street_address, |
| 56 | + city : city, |
| 57 | + postal_code : postal_code |
| 58 | + yrs_customer : yrs_customer |
| 59 | + pet : pet |
| 60 | +} |
| 61 | +; |
| 62 | +select * from customer_dv; |
| 63 | + |
| 64 | +--JSON Duality View on a couple of tables. We do need primary keys on the tables being used in the views |
| 65 | +alter table streams add constraint constraint_name primary key(cust_id,day_id, movie_id); |
| 66 | +--JSON of the customers with the movies that they streamed |
| 67 | +CREATE OR REPLACE JSON RELATIONAL DUALITY VIEW customer_streams_dv AS |
| 68 | +customer @insert @update @delete |
| 69 | +{ |
| 70 | + _id : cust_id, |
| 71 | + FirstName : first_name, |
| 72 | + LastName : last_name, |
| 73 | + age : age, |
| 74 | + yrs_customer : yrs_customer |
| 75 | + streams : streams @insert @update @delete |
| 76 | + [{ |
| 77 | + cust_id : cust_id |
| 78 | + day_id : day_id |
| 79 | + genre_id : genre_id |
| 80 | + movie_id : movie_id |
| 81 | + }] |
| 82 | +} |
| 83 | +; |
| 84 | +select * from customer_streams_dv; |
| 85 | +--Pull back the customers watching romance movies |
| 86 | +select * from customer_streams_dv |
| 87 | +where JSON_VALUE(data,'$.streams.genre_id')=19; |
| 88 | + |
| 89 | +/* Now to insert a new record into customers and streams we can do that through the Duality View. |
| 90 | +Here we select first from customer and from streams to show there is no value */ |
| 91 | +select * from customer where cust_id=555; |
| 92 | +select * from streams where cust_id=555; |
| 93 | +--Now do an insert to the DV to add a new customer and add a stream |
| 94 | +insert into customer_streams_dv values ('{ |
| 95 | + "_id" : 555, |
| 96 | + "FirstName" : "Michelle", |
| 97 | + "LastName" : "Jones", |
| 98 | + "age" : 36, |
| 99 | + "yrs_customer" : 0 , |
| 100 | + "streams" : [{ |
| 101 | + "day_id" : "2024-11-18T00:00:00", |
| 102 | + "genre_id" : 19, |
| 103 | + "movie_id" : 3694}]}'); |
| 104 | + |
| 105 | +commit; |
| 106 | +select * from customer where cust_id=555; |
| 107 | +select * from streams where cust_id=555; |
| 108 | +--now we have rows in both of the underlying relational tables |
| 109 | + |
| 110 | +/* With the JSON Collections and JSON Duality Views you can use API calls with GET and PUT to work |
| 111 | +with the JSON in the database. We have just shown here SQL access to the JSON. */ |
| 112 | + |
0 commit comments