|
| 1 | += JSON Schema: validate rows in a table |
| 2 | +:database-version: 23.2 |
| 3 | +:database-category: sql |
| 4 | + |
| 5 | +[[feature_summary]] |
| 6 | + |
| 7 | +JSON offers the flexibility of schemaless application design. Sometimes however, you might want some JSON data to conform to a schema. You might want to ensure that all data stored in a given column has the structure defined by a schema, or you might want to check whether a given JSON document has such a structure, before processing it. |
| 8 | + |
| 9 | +A JSON schema is a JSON document that respects the JSON Schema standard, which is a Request For Comments (RFC) draft. JSON schemas are in turn used to validate other JSON documents. Refer to the https://json-schema.org[JSON schema website] for more details. A JSON schema specifies the structure and the types of allowed values of JSON data that it considers valid. |
| 10 | + |
| 11 | +This example demonstrates how to query data in a relational table containing a JSON column and match it against a JSON schema. |
| 12 | + |
| 13 | +The following JSON schema ensures that only objects can be stored in the JSON column, containing both a `firstName` and `lastName` field with a minimum length of 1 character each. The numeric `salary` field is optional, however if defined, the salary must be greater than 10000. |
| 14 | + |
| 15 | +[source,json] |
| 16 | +[subs="verbatim"] |
| 17 | +---- |
| 18 | +{ |
| 19 | + "type": "object", |
| 20 | + "properties": { |
| 21 | + "firstName": { |
| 22 | + "type": "string", |
| 23 | + "minLength": 1 |
| 24 | + }, |
| 25 | + "lastName": { |
| 26 | + "type": "string", |
| 27 | + "minLength": 1 |
| 28 | + }, |
| 29 | + "salary": { |
| 30 | + "type": "number", |
| 31 | + "minimum": 10000 |
| 32 | + } |
| 33 | + }, |
| 34 | + "required": [ |
| 35 | + "firstName", |
| 36 | + "lastName" |
| 37 | + ] |
| 38 | +} |
| 39 | +---- |
| 40 | + |
| 41 | +[source,sql] |
| 42 | +[subs="verbatim"] |
| 43 | +---- |
| 44 | +CREATE TABLE json_demo( |
| 45 | + id NUMBER |
| 46 | + GENERATED ALWAYS AS IDENTITY, |
| 47 | + CONSTRAINT pk_json_demo PRIMARY KEY(id), |
| 48 | + jcol JSON NOT NULL |
| 49 | +); |
| 50 | +
|
| 51 | +-- will result in an error: salary too low |
| 52 | +INSERT INTO json_demo ( |
| 53 | + jcol |
| 54 | +) values ( |
| 55 | + JSON('{ "firstName": "Steven", "lastName": "King", "salary": 9999 }') |
| 56 | +); |
| 57 | +
|
| 58 | +-- will result in an error: required lastName not present |
| 59 | +INSERT INTO json_demo ( |
| 60 | + jcol |
| 61 | +) values ( |
| 62 | + JSON('{ "firstName": "Steven", "salary": 10001 }') |
| 63 | +); |
| 64 | +
|
| 65 | +-- will result in an error: lastName not spelled correctly |
| 66 | +INSERT INTO json_demo ( |
| 67 | + jcol |
| 68 | +) values ( |
| 69 | + JSON('{ "firstName": "Steven", "last_name": "King", "salary": 10001 }') |
| 70 | +); |
| 71 | +
|
| 72 | +-- this record is fine |
| 73 | +INSERT INTO json_demo ( |
| 74 | + jcol |
| 75 | +) values ( |
| 76 | + JSON('{ "firstName": "Steven", "lastName": "King" }') |
| 77 | +); |
| 78 | +
|
| 79 | +-- fetch valid data |
| 80 | +SELECT |
| 81 | + jcol |
| 82 | +FROM |
| 83 | + json_demo |
| 84 | +WHERE |
| 85 | + jcol IS JSON VALIDATE |
| 86 | + '{ |
| 87 | + "type": "object", |
| 88 | + "properties": { |
| 89 | + "firstName": { |
| 90 | + "type": "string", |
| 91 | + "minLength": 1 |
| 92 | + }, |
| 93 | + "lastName": { |
| 94 | + "type": "string", |
| 95 | + "minLength": 1 |
| 96 | + }, |
| 97 | + "salary": { |
| 98 | + "type": "number", |
| 99 | + "minimum": 10000 |
| 100 | + } |
| 101 | + }, |
| 102 | + "required": [ |
| 103 | + "firstName", |
| 104 | + "lastName" |
| 105 | + ] |
| 106 | + }'; |
| 107 | +---- |
| 108 | + |
| 109 | +.Result |
| 110 | +[source,sql] |
| 111 | +[subs="verbatim"] |
| 112 | +---- |
| 113 | +SQL> CREATE TABLE json_demo( |
| 114 | + 2 id NUMBER |
| 115 | + 3 GENERATED ALWAYS AS IDENTITY, |
| 116 | + 4 CONSTRAINT pk_json_demo PRIMARY KEY(id), |
| 117 | + 5 jcol JSON NOT NULL |
| 118 | + 6 ); |
| 119 | +
|
| 120 | +Table JSON_DEMO created. |
| 121 | +
|
| 122 | +SQL> -- will result in an error: salary too low |
| 123 | +SQL> INSERT INTO json_demo ( |
| 124 | + 2 jcol |
| 125 | + 3 ) values ( |
| 126 | + 4 JSON('{ "firstName": "Steven", "lastName": "King", "salary": 9999 }') |
| 127 | + 5 ); |
| 128 | +
|
| 129 | +1 row inserted. |
| 130 | +
|
| 131 | +SQL> -- will result in an error: required lastName not present |
| 132 | +SQL> INSERT INTO json_demo ( |
| 133 | + 2 jcol |
| 134 | + 3 ) values ( |
| 135 | + 4 JSON('{ "firstName": "Steven", "salary": 10001 }') |
| 136 | + 5 ); |
| 137 | +
|
| 138 | +1 row inserted. |
| 139 | +
|
| 140 | +SQL> -- will result in an error: lastName not spelled correctly |
| 141 | +SQL> INSERT INTO json_demo ( |
| 142 | + 2 jcol |
| 143 | + 3 ) values ( |
| 144 | + 4 JSON('{ "firstName": "Steven", "last_name": "King", "salary": 10001 }') |
| 145 | + 5 ); |
| 146 | +
|
| 147 | +1 row inserted. |
| 148 | +
|
| 149 | +SQL> INSERT INTO json_demo ( |
| 150 | + 2 jcol |
| 151 | + 3 ) values ( |
| 152 | + 4 JSON('{ "firstName": "Steven", "lastName": "King" }') |
| 153 | + 5 ); |
| 154 | +
|
| 155 | +1 row inserted. |
| 156 | +
|
| 157 | +SQL> -- fetch valid data |
| 158 | +SQL> SELECT |
| 159 | + 2 jcol |
| 160 | + 3 FROM |
| 161 | + 4 json_demo |
| 162 | + 5 WHERE |
| 163 | + 6 jcol IS JSON VALIDATE |
| 164 | + 7 '{ |
| 165 | + 8 "type": "object", |
| 166 | + 9 "properties": { |
| 167 | + 10 "firstName": { |
| 168 | + 11 "type": "string", |
| 169 | + 12 "minLength": 1 |
| 170 | + 13 }, |
| 171 | + 14 "lastName": { |
| 172 | + 15 "type": "string", |
| 173 | + 16 "minLength": 1 |
| 174 | + 17 }, |
| 175 | + 18 "salary": { |
| 176 | + 19 "type": "number", |
| 177 | + 20 "minimum": 10000 |
| 178 | + 21 } |
| 179 | + 22 }, |
| 180 | + 23 "required": [ |
| 181 | + 24 "firstName", |
| 182 | + 25 "lastName" |
| 183 | + 26 ] |
| 184 | + 27 }'; |
| 185 | +
|
| 186 | +JCOL |
| 187 | +___________________________________________ |
| 188 | +{"firstName":"Steven","lastName":"King"} |
| 189 | +---- |
| 190 | + |
| 191 | +== Benefits |
| 192 | + |
| 193 | +JSON is a popular format for data exchange, however with flexibility comes the risk of working with incomplete or wrong records. JSON schema allows developers to ensure better data quality. Using the `IS JSON VALIDATE` clause allows developers to vet JSON data in a column using a JSON schema. The above `SELECT` statement is the perfect partner for an `INSERT INTO _table_name_ SELECT ... IS JSON VALIDATE ...` |
| 194 | + |
| 195 | +== Further information |
| 196 | + |
| 197 | +* Availability: All Offerings |
| 198 | +* https://docs.oracle.com/en/database/oracle/oracle-database/23/adjsn/json-schema.html#GUID-980BD95E-D0EF-4E22-8E67-08CD419EE7A2[Documentation] |
0 commit comments