Skip to content

Commit e7c55d8

Browse files
hbaerusgvenzl
andauthoredAug 23, 2024
Update DualityViewTutorial.sql (#382)
Adjustments to mandatory "_id" column, introduced in 23.4 Co-authored-by: Gerald Venzl <gerald.venzl@oracle.com>
1 parent 4c17bcb commit e7c55d8

File tree

1 file changed

+31
-31
lines changed

1 file changed

+31
-31
lines changed
 

‎json-relational-duality/DualityViewTutorial.sql

+31-31
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,5 @@
11
/*
2-
** Copyright (c) 2023 Oracle and/or its affiliates
2+
** Copyright (c) 2024 Oracle and/or its affiliates
33
** The Universal Permissive License (UPL), Version 1.0
44
**
55
** Subject to the condition set forth below, permission is hereby granted to any
@@ -44,7 +44,7 @@
4444
-- through SQL.
4545
--
4646
-- PREREQUISITES
47-
-- Ensure that you have Oracle database 23c installed and running on a
47+
-- Ensure that you have Oracle database 23ai installed and running on a
4848
-- port. Ensure that the compatible parameter is set to 23.0.0.0.
4949
--
5050
-- USAGE
@@ -55,13 +55,6 @@
5555
-- DIRECTORY, DROP ANY DIRECTORY, DBA TO janus IDENTIFIED BY janus;
5656
--
5757
-- NOTES
58-
-- Oracle Database 23c Free - Developer Release is the first release of
59-
-- the next-generation Oracle Database, allowing developers a head-start
60-
-- on building applications with innovative 23c features that simplify
61-
-- development of modern data-driven apps. The entire feature set of
62-
-- Oracle Database 23c is planned to be generally available within the
63-
-- next 12 months.
64-
--
6558
-- Please go through the duality view documentation
6659
-- (https://docs.oracle.com/en/database/oracle/oracle-database/23/jsnvu/index.html)
6760
-- to learn more about duality views and their advantages.
@@ -137,6 +130,14 @@ CREATE TABLE driver_race_map
137130
-- Create a trigger on the driver_race_map table to populate
138131
-- the points fields in team and driver based on race results.
139132
--
133+
-- For people that are not familiar with Formula One: Depending on the position in a race,
134+
-- both the racing team and the driver get points. There are two championships in Formula One:
135+
-- one for the drivers and one for the teams. The team championship is called the Constructors'
136+
-- Championship and the scoring system is the same as in the Drivers' Championship — except the
137+
-- points from both drivers on a team are tallied together.
138+
-- If you want to read up more, then check out
139+
-- - https://www.redbull.com/in-en/formula-1-points-system-guide
140+
--
140141
CREATE OR REPLACE TRIGGER driver_race_map_trigger
141142
BEFORE INSERT ON driver_race_map
142143
FOR EACH ROW
@@ -182,7 +183,7 @@ END;
182183

183184
-- Creation using SQL syntax
184185
CREATE OR REPLACE JSON RELATIONAL DUALITY VIEW race_dv AS
185-
SELECT JSON {'raceId' : r.race_id,
186+
SELECT JSON {'_id' : r.race_id,
186187
'name' : r.name,
187188
'laps' : r.laps WITH NOUPDATE,
188189
'date' : r.race_date,
@@ -204,7 +205,7 @@ CREATE OR REPLACE JSON RELATIONAL DUALITY VIEW race_dv AS
204205
CREATE OR REPLACE JSON RELATIONAL DUALITY VIEW race_dv AS
205206
race @insert @update @delete
206207
{
207-
raceId : race_id
208+
_id : race_id
208209
name : name
209210
laps : laps @noUpdate
210211
date : race_date
@@ -229,7 +230,7 @@ CREATE OR REPLACE JSON RELATIONAL DUALITY VIEW race_dv AS
229230

230231
-- Creation using SQL syntax
231232
CREATE OR REPLACE JSON RELATIONAL DUALITY VIEW driver_dv AS
232-
SELECT JSON {'driverId' : d.driver_id,
233+
SELECT JSON {'_id' : d.driver_id,
233234
'name' : d.name,
234235
'points' : d.points,
235236
UNNEST
@@ -254,7 +255,7 @@ CREATE OR REPLACE JSON RELATIONAL DUALITY VIEW driver_dv AS
254255
CREATE OR REPLACE JSON RELATIONAL DUALITY VIEW driver_dv AS
255256
driver @insert @update @delete
256257
{
257-
driverId : driver_id
258+
_id : driver_id
258259
name : name
259260
points : points
260261
team @noInsert @noUpdate @noDelete @unnest
@@ -282,7 +283,7 @@ CREATE OR REPLACE JSON RELATIONAL DUALITY VIEW driver_dv AS
282283

283284
-- Creation using SQL syntax
284285
CREATE OR REPLACE JSON RELATIONAL DUALITY VIEW team_dv AS
285-
SELECT JSON {'teamId' : t.team_id,
286+
SELECT JSON {'_id' : t.team_id,
286287
'name' : t.name,
287288
'points' : t.points,
288289
'driver' :
@@ -298,7 +299,7 @@ CREATE OR REPLACE JSON RELATIONAL DUALITY VIEW team_dv AS
298299
CREATE OR REPLACE JSON RELATIONAL DUALITY VIEW team_dv AS
299300
team @insert @update @delete
300301
{
301-
teamId : team_id
302+
_id : team_id
302303
name : name
303304
points : points
304305
driver : driver @insert @update
@@ -330,7 +331,7 @@ SELECT json_serialize(data PRETTY) FROM team_dv;
330331
-- This automatically populates the driver and team table as well as the
331332
-- driver collection.
332333
--
333-
INSERT INTO team_dv VALUES ('{"teamId" : 301,
334+
INSERT INTO team_dv VALUES ('{"_id" : 301,
334335
"name" : "Red Bull",
335336
"points" : 0,
336337
"driver" : [ {"driverId" : 101,
@@ -340,7 +341,7 @@ INSERT INTO team_dv VALUES ('{"teamId" : 301,
340341
"name" : "Sergio Perez",
341342
"points" : 0} ]}');
342343

343-
INSERT INTO team_dv VALUES ('{"teamId" : 302,
344+
INSERT INTO team_dv VALUES ('{"_id" : 302,
344345
"name" : "Ferrari",
345346
"points" : 0,
346347
"driver" : [ {"driverId" : 103,
@@ -350,7 +351,7 @@ INSERT INTO team_dv VALUES ('{"teamId" : 302,
350351
"name" : "Carlos Sainz Jr",
351352
"points" : 0} ]}');
352353

353-
INSERT INTO team_dv VALUES ('{"teamId" : 2,
354+
INSERT INTO team_dv VALUES ('{"_id" : 2,
354355
"name" : "Mercedes",
355356
"points" : 0,
356357
"driver" : [ {"driverId" : 105,
@@ -363,19 +364,19 @@ INSERT INTO team_dv VALUES ('{"teamId" : 2,
363364
-- Insert a collection of race documents into RACE_DV.
364365
-- This automatically populates the race table.
365366
--
366-
INSERT INTO race_dv VALUES ('{"raceId" : 201,
367+
INSERT INTO race_dv VALUES ('{"_id" : 201,
367368
"name" : "Bahrain Grand Prix",
368369
"laps" : 57,
369370
"date" : "2022-03-20T00:00:00",
370371
"podium" : {}}');
371372

372-
INSERT INTO race_dv VALUES ('{"raceId" : 202,
373+
INSERT INTO race_dv VALUES ('{"_id" : 202,
373374
"name" : "Saudi Arabian Grand Prix",
374375
"laps" : 50,
375376
"date" : "2022-03-27T00:00:00",
376377
"podium" : {}}');
377378

378-
INSERT INTO race_dv VALUES ('{"raceId" : 203,
379+
INSERT INTO race_dv VALUES ('{"_id" : 203,
379380
"name" : "Australian Grand Prix",
380381
"laps" : 58,
381382
"date" : "2022-04-09T00:00:00",
@@ -413,7 +414,7 @@ SELECT json_serialize(data PRETTY) FROM race_dv;
413414
-- is used by the REST interface to translate QBEs.
414415
--
415416
SELECT json_serialize(data PRETTY)
416-
FROM race_dv WHERE json_value(data, '$.raceId') = 201;
417+
FROM race_dv WHERE json_value(data, '$._id') = 201;
417418

418419
-- Project specific document fields.
419420
-- In SQL, specific documents fields can be requested using the KEEP operator
@@ -448,7 +449,7 @@ SELECT json_serialize(json_transform(data, KEEP '$.name', '$.team') PRETTY)
448449
--
449450
UPDATE race_dv dv
450451
SET data = ('{_metadata : {"etag" : "2E8DC09543DD25DC7D588FB9734D962B"},
451-
"raceId" : 201,
452+
"_id" : 201,
452453
"name" : "Bahrain Grand Prix",
453454
"laps" : 57,
454455
"date" : "2022-03-20T00:00:00",
@@ -475,16 +476,15 @@ UPDATE race_dv dv
475476
"position" : 4,
476477
"driverId" : 105,
477478
"name" : "George Russell"} ]}')
478-
WHERE dv.data.raceId = 201;
479+
WHERE dv.data."_id" = 201;
479480

480481
COMMIT;
481482

482483
-- See the results for the Bahrain Grand Prix.
483484
-- You can use a predicate on the primary key field to query by ID.
484485
--
485486
SELECT json_serialize(data PRETTY)
486-
FROM race_dv dv WHERE dv.data.raceId = 201;
487-
487+
FROM race_dv dv WHERE dv.data."_id" = 201;
488488

489489
------------------------------------------------------------------------------
490490
-- Step 7: Update specific fields in the document identified by a predicate --
@@ -542,7 +542,7 @@ SELECT json_serialize(data PRETTY) FROM team_dv dv
542542
--
543543
UPDATE team_dv dv
544544
SET data = ('{_metadata : {"etag" : "855840B905C8CAFA99FB9CBF813992E5"},
545-
"teamId" : 2,
545+
"_id" : 2,
546546
"name" : "Mercedes",
547547
"points" : 40,
548548
"driver" : [ {"driverId" : 106,
@@ -555,7 +555,7 @@ UPDATE team_dv dv
555555

556556
UPDATE team_dv dv
557557
SET data = ('{_metadata : {"etag" : "DA69DD103E8BAE95A0C09811B7EC9628"},
558-
"teamId" : 302,
558+
"_id" : 302,
559559
"name" : "Ferrari",
560560
"points" : 30,
561561
"driver" : [ {"driverId" : 105,
@@ -594,7 +594,7 @@ SELECT json_serialize(data PRETTY) FROM driver_dv dv
594594
--
595595
UPDATE driver_dv dv
596596
SET DATA = ('{_metadata : {"etag" : "FCD4CEC63897F60DEA1EC2F64D3CE53A"},
597-
"driverId" : 103,
597+
"_id" : 103,
598598
"name" : "Charles Leclerc",
599599
"points" : 25,
600600
"teamId" : 2,
@@ -609,7 +609,7 @@ UPDATE driver_dv dv
609609
}
610610
]
611611
}')
612-
WHERE dv.data.driverId = 103;
612+
WHERE dv.data."_id" = 103;
613613

614614

615615
----------------------------------
@@ -623,7 +623,7 @@ UPDATE driver_dv dv
623623
-- valid SQL expression, e.g. equality on primary key, some condition using
624624
-- simplified syntax, or JSON function, such as json_value or json_exists.
625625
--
626-
DELETE FROM race_dv dv WHERE dv.data.raceId = 201;
626+
DELETE FROM race_dv dv WHERE dv.data."_id" = 201;
627627

628628
SELECT json_serialize(data PRETTY) FROM race_dv;
629629
SELECT json_serialize(data PRETTY) FROM driver_dv;

0 commit comments

Comments
 (0)
Failed to load comments.