|
| 1 | +# Introduction to JSON Collections |
| 2 | + |
| 3 | +## Introduction |
| 4 | + |
| 5 | +This lab walks you through the steps to create and access JSON collections in the Oracle database. |
| 6 | + |
| 7 | +Estimated Lab Time: 10 minutes |
| 8 | + |
| 9 | +### About JSON Collections |
| 10 | + |
| 11 | +JSON collections are database objects that store or otherwise provide a set of JSON documents. Client applications typically use operations provided by document APIs to manipulate collections and their documents. They can also use SQL to do so. In Oracle Database, a JSON collection is a special table or view that provides JSON documents in a single JSON-type object column named DATA. In this lab, we will be using JSON collection tables. |
| 12 | + |
| 13 | +### Objectives |
| 14 | + |
| 15 | +In this lab, you will: |
| 16 | + |
| 17 | +* Learn how to create a JSON collection table |
| 18 | +* Learn how to access JSON collection tables |
| 19 | +* Learn about schema flexibility in JSON collections |
| 20 | +* Learn about the data duplication problem with JSON collections |
| 21 | + |
| 22 | +### Prerequisites |
| 23 | + |
| 24 | +* Oracle Autonomous Database 23ai provisioned or one running in a LiveLabs environment |
| 25 | + |
| 26 | +## Task 1: Create a JSON Collection and Load Data |
| 27 | + |
| 28 | +In this task, we will create a JSON collection table called `attendee` that represents a collection of attendees for a database conference. |
| 29 | + |
| 30 | +1. Create the `attendee` collection. |
| 31 | + |
| 32 | + ```sql |
| 33 | + <copy> |
| 34 | + DROP TABLE IF EXISTS attendee; |
| 35 | + CREATE JSON COLLECTION TABLE IF NOT EXISTS attendee; |
| 36 | + </copy> |
| 37 | + ``` |
| 38 | + |
| 39 | + This creates a table with a single JSON-type object column named `DATA`. Because it's ultimately "just a table", you can use a JSON collection table in most of the ways that you use a regular table. In particular, you can use GoldenGate to replicate a collection table between databases, including between Oracle Database and JSON document databases, such as MongoDB. |
| 40 | + |
| 41 | +2. Insert data into the `attendee` collection. |
| 42 | + |
| 43 | + ```sql |
| 44 | + <copy> |
| 45 | + INSERT INTO attendee VALUES |
| 46 | + ('{"_id" : 1, |
| 47 | + "firstName" : "Beda", |
| 48 | + "lastName" : "Hammerschmidt", |
| 49 | + "nickName" : "Dr. JSON", |
| 50 | + "age" : 20, |
| 51 | + "phoneNumber" : "222-111-021", |
| 52 | + "coffeeItem" : "Espresso", |
| 53 | + "lectures" : [ {"id" : 10, "lectureName" : "JSON and SQL", "credits" : 3}, |
| 54 | + {"id" : 20, "lectureName" : "PL/SQL or Javascript", "credits" : 4}, |
| 55 | + {"id" : 30, "lectureName" : "MongoDB API Internals", "credits" : 5}, |
| 56 | + {"id" : 40, "lectureName" : "Oracle ADB on iPhone", "credits" : 3}, |
| 57 | + {"id" : 50, "lectureName" : "JSON Duality Views", "credits" : 3} ]}'); |
| 58 | + INSERT INTO attendee VALUES |
| 59 | + ('{"_id" : 2, |
| 60 | + "firstName" : "Hermann", |
| 61 | + "lastName" : "Baer", |
| 62 | + "age" : 22, |
| 63 | + "phoneNumber" : "222-112-023", |
| 64 | + "coffeeItem" : "Cappuccino", |
| 65 | + "lectures" : [ {"id" : 10, "lectureName" : "JSON and SQL", "credits" : 3}, |
| 66 | + {"id" : 30, "lectureName" : "MongoDB API Internals", "credits" : 5}, |
| 67 | + {"id" : 40, "lectureName" : "JSON Duality Views", "credits" : 3} ]}'); |
| 68 | + INSERT INTO attendee VALUES |
| 69 | + ('{"_id" : 3, |
| 70 | + "firstName" : "Shashank", |
| 71 | + "lastName" : "Gugnani", |
| 72 | + "nickName" : "SG", |
| 73 | + "age" : 23, |
| 74 | + "phoneNumber" : "222-112-024", |
| 75 | + "coffeeItem" : "Americano", |
| 76 | + "lectures" : [ {"id" : 10, "lectureName" : "JSON and SQL", "credits" : 3}, |
| 77 | + {"id" : 30, "lectureName" : "MongoDB API Internals", "credits" : 5} ]}'); |
| 78 | + INSERT INTO attendee VALUES |
| 79 | + ('{"_id" : 4, |
| 80 | + "firstName" : "Julian", |
| 81 | + "lastName" : "Dontcheff", |
| 82 | + "nickName" : "Jul", |
| 83 | + "age" : 24, |
| 84 | + "phoneNumber" : "222-113-025", |
| 85 | + "coffeeItem" : "Decaf", |
| 86 | + "lectures" : [ {"id" : 40, "lectureName" : "JSON Duality Views", "credits" : 3} ]}'); |
| 87 | + |
| 88 | + COMMIT; |
| 89 | + </copy> |
| 90 | + ``` |
| 91 | + |
| 92 | + As you see, it looks like a normal SQL `INSERT` statement. The only difference is that we specified a proper JSON document as input for our DATA column. Copy the SQL statement and execute it in the SQL worksheet. |
| 93 | + |
| 94 | +## Task 2: Access a JSON Collection |
| 95 | + |
| 96 | +1. Find a document in the `attendee` collection |
| 97 | + |
| 98 | + ```sql |
| 99 | + <copy>SELECT a.data FROM attendee a WHERE a.data."_id" = 1;</copy> |
| 100 | + ``` |
| 101 | + |
| 102 | +  |
| 103 | + |
| 104 | + We can also select specific fields within the JSON document by using the dot notation to peek inside the document. |
| 105 | + |
| 106 | + ```sql |
| 107 | + <copy> |
| 108 | + SELECT a.data.lastName || ', ' || a.data.firstName as name, |
| 109 | + a.data.nickName as nick_name |
| 110 | + FROM attendee a |
| 111 | + WHERE a.data."_id" = 1; |
| 112 | + </copy> |
| 113 | + ``` |
| 114 | + |
| 115 | +  |
| 116 | + |
| 117 | +2. Add a field to an existing document. We will add a `country` field to Julian's attendee document to specify his country of origin. |
| 118 | + |
| 119 | + ```sql |
| 120 | + <copy> |
| 121 | + UPDATE attendee a |
| 122 | + SET a.data = JSON_TRANSFORM(a.data, SET '$.country' = 'Finland') |
| 123 | + WHERE a.data."_id" = 4; |
| 124 | + |
| 125 | + COMMIT; |
| 126 | + </copy> |
| 127 | + ``` |
| 128 | + |
| 129 | +3. Query the updated document. It should now contain the `country` field, which can also be queried using dot notation. |
| 130 | + |
| 131 | + ```sql |
| 132 | + <copy>SELECT a.data FROM attendee a WHERE a.data."_id" = 4;</copy> |
| 133 | + ``` |
| 134 | + |
| 135 | +  |
| 136 | + |
| 137 | + ```sql |
| 138 | + <copy> |
| 139 | + SELECT a.data.lastName || ', ' || a.data.firstName as name, |
| 140 | + a.data.nickName as nick_name, |
| 141 | + a.data.country as country |
| 142 | + FROM attendee a |
| 143 | + WHERE a.data."_id" = 4; |
| 144 | + </copy> |
| 145 | + ``` |
| 146 | + |
| 147 | +  |
| 148 | + |
| 149 | +## Task 3: Update Shared Information |
| 150 | + |
| 151 | +In this task, we will update lecture name for lecture id 40, from "JSON Duality Views" to "JSON Relational Duality Views". Since lecture information is duplicated across multiple attendee documents, we must update the lecture name in all documents containing that lecture. |
| 152 | + |
| 153 | +1. Find all document that contain lecture id 40. We will use a `JSON_EXISTS` predicate to find all such documents. |
| 154 | + |
| 155 | + ```sql |
| 156 | + <copy> |
| 157 | + SELECT data |
| 158 | + FROM attendee |
| 159 | + WHERE JSON_EXISTS(data, '$.lectures[*]?(@.id == 40)'); |
| 160 | + </copy> |
| 161 | + ``` |
| 162 | + |
| 163 | +  |
| 164 | + |
| 165 | +2. Update the lecture name in all documents containing lecture id 40. We will use a `JSON_EXISTS` predicate to find all such documents, then use `JSON_TRANSFORM` to update the lecture name only for the matching lecture id. |
| 166 | + |
| 167 | + ```sql |
| 168 | + <copy> |
| 169 | + UPDATE attendee |
| 170 | + SET data = JSON_TRANSFORM( |
| 171 | + data, |
| 172 | + SET '$.lectures[*]?(@.id == 40).lectureName' = 'JSON Relational Duality Views' |
| 173 | + ) |
| 174 | + WHERE JSON_EXISTS(data, '$.lectures[*]?(@.id == 40)'); |
| 175 | + |
| 176 | + COMMIT; |
| 177 | + </copy> |
| 178 | + ``` |
| 179 | + |
| 180 | + This statement updates three documents, each of which references lecture id 40. |
| 181 | + |
| 182 | +3. Select all documents from the view to see the updated documents. |
| 183 | + |
| 184 | + ```sql |
| 185 | + <copy> |
| 186 | + SELECT data |
| 187 | + FROM attendee; |
| 188 | + </copy> |
| 189 | + ``` |
| 190 | + |
| 191 | +  |
| 192 | + |
| 193 | + We can see that the lecture name for lecture id 40 has now been updated consistently everywhere. It is easy to see the problem with JSON collections containing duplicate data - Any update to duplicate data must be managed carefully and kept consistent manually. In the next lab, we will see how duality views effectively solves this problem. |
| 194 | + |
| 195 | +You may now **proceed to the next lab**. |
| 196 | + |
| 197 | +## Learn More |
| 198 | + |
| 199 | +* [JSON Collections](https://docs.oracle.com/en/database/oracle/oracle-database/23/adjsn/json-collections.html) |
| 200 | +* [JSON-Relational Duality Views](https://docs.oracle.com/en/database/oracle/oracle-database/23/jsnvu/overview-json-relational-duality-views.html) |
| 201 | + |
| 202 | +## Acknowledgements |
| 203 | + |
| 204 | +* **Author** - Shashank Gugnani |
| 205 | +* **Contributors** - Julian Dontcheff |
| 206 | +* **Last Updated By/Date** - Shashank Gugnani, August 2025 |
0 commit comments