Skip to content

Commit 3fe00ba

Browse files
committed
added tests and fixed errors and type casts
1 parent e302fe2 commit 3fe00ba

File tree

2 files changed

+227
-24
lines changed

2 files changed

+227
-24
lines changed

postgres-json-schema--0.2.0.sql

+36-24
Original file line numberDiff line numberDiff line change
@@ -4,21 +4,21 @@ CREATE TYPE json_schema_validation_result AS (
44
);
55

66

7-
CREATE OR REPLACE FUNCTION json_schema_validation_result_as_bool (json_schema_validation_result) RETURNS bool AS $$
7+
CREATE OR REPLACE FUNCTION json_schema_validation_result_as_bool (@extschema@.json_schema_validation_result) RETURNS bool AS $$
88
SELECT ($1).error IS NULL;
99
$$ LANGUAGE SQL IMMUTABLE;
1010

11-
CREATE OR REPLACE FUNCTION json_schema_validation_result_array_as_bool (json_schema_validation_result[]) RETURNS bool AS $$
12-
SELECT $1 IS NULL OR true = ALL ($1);
11+
CREATE OR REPLACE FUNCTION json_schema_validation_result_array_as_bool (@extschema@.json_schema_validation_result[]) RETURNS bool AS $$
12+
SELECT $1 IS NULL OR true = ALL ($1::bool[]);
1313
$$ LANGUAGE SQL IMMUTABLE;
1414

1515
CREATE CAST ( json_schema_validation_result AS bool )
1616
WITH FUNCTION @[email protected]_schema_validation_result_as_bool(json_schema_validation_result)
17-
AS IMPLICIT;
17+
AS ASSIGNMENT;
1818

1919
CREATE CAST ( json_schema_validation_result[] AS bool )
2020
WITH FUNCTION @[email protected]_schema_validation_result_array_as_bool(json_schema_validation_result[])
21-
AS IMPLICIT;
21+
AS ASSIGNMENT;
2222

2323

2424

@@ -93,12 +93,24 @@ CREATE OR REPLACE FUNCTION validate_json_schema(schema jsonb, data jsonb, root_s
9393
SELECT @[email protected]_json_schema_validations(schema, data, root_schema, ARRAY []::text[], string_as_number)::bool;
9494
$f$ LANGUAGE SQL IMMUTABLE ;
9595

96-
CREATE OR REPLACE FUNCTION json_schema_check_constraint(schema jsonb, data jsonb, string_as_number bool default true) RETURNS bool AS $$
97-
DECLARE result json_schema_validation_result[];
96+
CREATE OR REPLACE FUNCTION json_schema_check_constraint(
97+
schema jsonb,
98+
data jsonb,
99+
string_as_number bool default true,
100+
table_name text default '',
101+
column_name text default ''
102+
) RETURNS bool AS $$
103+
DECLARE
104+
result json_schema_validation_result[];
98105
BEGIN
99-
result := @extschema@.get_json_schema_validations(schema, data, schema, '{}'::text[], string_as_number := string_as_number);
106+
result := get_json_schema_validations(schema, data, schema, '{}'::text[], string_as_number := string_as_number);
100107
IF (NOT result) THEN
101-
RAISE check_violation USING MESSAGE = 'json_schema_validation_failed', DETAIL = result;
108+
RAISE check_violation USING
109+
MESSAGE = 'json_schema_validation_failed',
110+
DETAIL = to_jsonb(result),
111+
-- HINT = v_value,
112+
TABLE = table_name,
113+
COLUMN = column_name;
102114
END IF;
103115
RETURN true;
104116
END;
@@ -109,7 +121,7 @@ $$ LANGUAGE plpgsql IMMUTABLE ;
109121
CREATE OR REPLACE FUNCTION _validate_json_multiple_schemas(
110122
schemas_array jsonb, data jsonb, root_schema jsonb, schema_path text[], string_as_number bool,
111123
OUT validation_booleans bool[],
112-
OUT all_errors json_schema_validation_result[]
124+
OUT all_errors @extschema@.json_schema_validation_result[]
113125
) AS $f$
114126
WITH schema_validations AS (
115127
SELECT q FROM jsonb_array_elements(schemas_array) sub_schema,
@@ -122,7 +134,7 @@ $f$ LANGUAGE SQL IMMUTABLE ;
122134

123135

124136
CREATE OR REPLACE FUNCTION get_json_schema_validations(schema jsonb, data jsonb, root_schema jsonb, schema_path text[], string_as_number bool)
125-
RETURNS json_schema_validation_result[] AS $f$
137+
RETURNS @extschema@.json_schema_validation_result[] AS $f$
126138
DECLARE
127139
prop text;
128140
item jsonb;
@@ -133,7 +145,7 @@ DECLARE
133145
additionalItems jsonb;
134146
pattern text;
135147
props text[];
136-
result json_schema_validation_result[];
148+
result @extschema@.json_schema_validation_result[];
137149
q_result record;
138150
BEGIN
139151
IF root_schema IS NULL THEN
@@ -160,7 +172,7 @@ BEGIN
160172
ELSE
161173
types = ARRAY[schema->>'type'];
162174
END IF;
163-
IF (SELECT NOT bool_or(@extschema@._validate_json_schema_type(type, data)) FROM unnest(types) type) THEN
175+
IF (SELECT NOT bool_or(@extschema@._validate_json_schema_type(type, data, string_as_number)) FROM unnest(types) type) THEN
164176
RETURN ARRAY [(schema_path, format('%s is not a valid type: %s', jsonb_typeof(data), types))];
165177
END IF;
166178
END IF;
@@ -215,7 +227,7 @@ BEGIN
215227
IF prefixItems IS NOT NULL THEN
216228
SELECT array_agg(q) INTO result
217229
FROM jsonb_array_elements(prefixItems) WITH ORDINALITY AS t(sub_schema, i),
218-
@[email protected]_json_schema_validations(sub_schema, data->(i::int - 1), root_schema, schema_path || i::text, string_as_number) q1, unnest(q1) q
230+
@[email protected]_json_schema_validations(sub_schema, data->(i::int - 1), root_schema, schema_path || (i - 1)::text, string_as_number) q1, unnest(q1) q
219231
WHERE i <= jsonb_array_length(data);
220232
IF NOT result THEN
221233
RETURN result;
@@ -232,7 +244,7 @@ BEGIN
232244
IF jsonb_typeof(additionalItems) = 'object' THEN
233245
SELECT array_agg(q) INTO result
234246
FROM jsonb_array_elements(data) WITH ORDINALITY AS t(elem, i),
235-
@[email protected]_json_schema_validations(additionalItems, elem, root_schema, schema_path || i::text, string_as_number) AS q1, unnest(q1) q
247+
@[email protected]_json_schema_validations(additionalItems, elem, root_schema, schema_path || (i - 1)::text, string_as_number) AS q1, unnest(q1) q
236248
WHERE i > coalesce(jsonb_array_length(prefixItems), 0) AND NOT q LIMIT 1;
237249

238250
IF NOT result THEN
@@ -281,22 +293,22 @@ BEGIN
281293
IF schema ? 'anyOf' THEN
282294
q_result := @extschema@._validate_json_multiple_schemas(schema->'anyOf', data, root_schema, schema_path, string_as_number);
283295
IF NOT (SELECT true = any (q_result.validation_booleans)) THEN
284-
RETURN q_result.all_errors || (schema_path, 'does not match any of the required schemas')::json_schema_validation_result;
296+
RETURN q_result.all_errors || (schema_path, 'does not match any of the required schemas')::@extschema@.json_schema_validation_result;
285297
END IF;
286298
END IF;
287299

288300
IF schema ? 'allOf' THEN
289301
q_result := @extschema@._validate_json_multiple_schemas(schema->'allOf', data, root_schema, schema_path, string_as_number);
290302
IF NOT (SELECT true = all(q_result.validation_booleans)) THEN
291-
RETURN q_result.all_errors || (schema_path, 'does not match all of the required schemas')::json_schema_validation_result;
303+
RETURN q_result.all_errors || (schema_path, 'does not match all of the required schemas')::@extschema@.json_schema_validation_result;
292304
END IF;
293305
END IF;
294306

295307
IF schema ? 'oneOf' THEN
296308
q_result := @extschema@._validate_json_multiple_schemas(schema->'oneOf', data, root_schema, schema_path, string_as_number);
297309
SELECT count(a::bool) INTO idx FROM unnest(q_result.validation_booleans) a WHERE a = true;
298310
IF (idx != 1) THEN
299-
RETURN ARRAY [(schema_path, format('should match exactly one of the schemas, but matches %s', idx))::json_schema_validation_result];
311+
RETURN ARRAY [(schema_path, format('should match exactly one of the schemas, but matches %s', idx))::@extschema@.json_schema_validation_result];
300312
END IF;
301313
END IF;
302314

@@ -319,7 +331,7 @@ BEGIN
319331
END IF;
320332
ELSE
321333
SELECT array_agg(q) INTO result FROM unnest(props) key, @[email protected]_json_schema_validations(schema->'additionalProperties', data->key, root_schema, schema_path || key, string_as_number) q1, unnest(q1) q;
322-
IF NOT (true = all(result)) THEN
334+
IF NOT (true = all(result::bool[])) THEN
323335
RETURN result;
324336
END IF;
325337
END IF;
@@ -338,7 +350,7 @@ BEGIN
338350
END IF;
339351

340352
result := @[email protected]_json_schema_validations(root_schema #> path, data, root_schema, schema_path, string_as_number);
341-
IF NOT (true = all(result)) THEN
353+
IF NOT (true = all(result::bool[])) THEN
342354
RETURN result;
343355
END IF;
344356
END IF;
@@ -402,14 +414,14 @@ BEGIN
402414
IF schema ? 'maxItems' AND jsonb_typeof(data) = 'array' THEN
403415
SELECT count(*) INTO idx FROM jsonb_array_elements(data);
404416
IF idx > (schema->>'maxItems')::numeric THEN
405-
RETURN ARRAY [(schema_path, format('field items count %s exceeds maxItems of %s', idx, schema->'maxItems'))];
417+
RETURN ARRAY [(schema_path, format('items count of %s exceeds maxItems of %s', idx, schema->'maxItems'))];
406418
END IF;
407419
END IF;
408420

409421
IF schema ? 'minItems' AND jsonb_typeof(data) = 'array' THEN
410422
SELECT count(*) INTO idx FROM jsonb_array_elements(data);
411423
IF idx < (schema->>'minItems')::numeric THEN
412-
RETURN ARRAY [(schema_path, format('field items count %s is less than minItems of %s', idx, schema->'minItems'))];
424+
RETURN ARRAY [(schema_path, format('items count of %s is less than minItems of %s', idx, schema->'minItems'))];
413425
END IF;
414426
END IF;
415427

@@ -477,7 +489,7 @@ BEGIN
477489
END IF;
478490
END IF;
479491

480-
RETURN '{}'::json_schema_validation_result[];
492+
RETURN '{}'::@extschema@.json_schema_validation_result[];
481493
END;
482494
$f$ LANGUAGE 'plpgsql' VOLATILE ;
483495

@@ -691,7 +703,7 @@ CREATE OR REPLACE FUNCTION json_schema_resolve_ids_to_paths (
691703
ELSEIF jsonb_typeof(schema) = 'array' THEN
692704
RETURN QUERY SELECT q.*
693705
FROM jsonb_array_elements(schema) WITH ORDINALITY t(elem, idx),
694-
@[email protected]_schema_resolve_ids_to_paths(elem, path || (idx -1)::text, base_uri, base_path) q;
706+
@[email protected]_schema_resolve_ids_to_paths(elem, path || (idx - 1)::text, base_uri, base_path) q;
695707

696708
END IF;
697709
resolved_path := path;

tests.sql

+191
Original file line numberDiff line numberDiff line change
@@ -129,3 +129,194 @@ BEGIN
129129
ASSERT (SELECT '{definitions,A,definitions,B,part1,nested}'::text[] = json_schema_resolve_ref('http://localhost:1234/nested.json#foo/part1/nested', NULL, NULL, '{"http://localhost:1234/root": [], "http://localhost:1234/nested.json": ["definitions", "A"], "http://localhost:1234/nested.json#foo": ["definitions", "A", "definitions", "B"]}'));
130130
END;
131131
$f$;
132+
133+
134+
CREATE OR REPLACE FUNCTION test_raises_exception(
135+
text,
136+
expected jsonb,
137+
OUT result bool, OUT msg text
138+
) AS $f$
139+
DECLARE
140+
RETURNED_SQLSTATE text;
141+
COLUMN_NAME text;
142+
CONSTRAINT_NAME text;
143+
PG_DATATYPE_NAME text;
144+
MESSAGE_TEXT text;
145+
TABLE_NAME text;
146+
SCHEMA_NAME text;
147+
PG_EXCEPTION_DETAIL text;
148+
PG_EXCEPTION_HINT text;
149+
PG_EXCEPTION_CONTEXT text;
150+
v_vars jsonb;
151+
v_key text;
152+
v_value text;
153+
BEGIN
154+
result := false;
155+
msg := 'No exception raised';
156+
execute ( $1 );
157+
EXCEPTION
158+
WHEN others THEN
159+
GET STACKED DIAGNOSTICS
160+
RETURNED_SQLSTATE := RETURNED_SQLSTATE,
161+
COLUMN_NAME := COLUMN_NAME,
162+
CONSTRAINT_NAME := CONSTRAINT_NAME,
163+
PG_DATATYPE_NAME := PG_DATATYPE_NAME,
164+
MESSAGE_TEXT := MESSAGE_TEXT,
165+
TABLE_NAME := TABLE_NAME,
166+
SCHEMA_NAME := SCHEMA_NAME,
167+
PG_EXCEPTION_DETAIL := PG_EXCEPTION_DETAIL,
168+
PG_EXCEPTION_HINT := PG_EXCEPTION_HINT,
169+
PG_EXCEPTION_CONTEXT := PG_EXCEPTION_CONTEXT;
170+
171+
v_vars := jsonb_build_object(
172+
'RETURNED_SQLSTATE', RETURNED_SQLSTATE,
173+
'COLUMN_NAME', COLUMN_NAME,
174+
'CONSTRAINT_NAME', CONSTRAINT_NAME,
175+
'PG_DATATYPE_NAME', PG_DATATYPE_NAME,
176+
'MESSAGE_TEXT', MESSAGE_TEXT,
177+
'TABLE_NAME', TABLE_NAME,
178+
'SCHEMA_NAME', SCHEMA_NAME,
179+
'PG_EXCEPTION_DETAIL', PG_EXCEPTION_DETAIL,
180+
'PG_EXCEPTION_HINT', PG_EXCEPTION_HINT,
181+
'PG_EXCEPTION_CONTEXT', PG_EXCEPTION_CONTEXT
182+
);
183+
IF expected IS NOT NULL THEN
184+
FOR v_key, v_value IN SELECT k, coalesce(expected->>k, expected->>lower(k)) FROM jsonb_object_keys(v_vars) k LOOP
185+
186+
IF v_value IS NOT NULL AND v_vars->>v_key NOT ILIKE v_value THEN
187+
result := false;
188+
msg := format('%s: %s != Expected %s', v_key, v_vars->>v_key, v_value);
189+
RETURN;
190+
END IF;
191+
END LOOP;
192+
END IF;
193+
194+
result := true;
195+
msg := MESSAGE_TEXT;
196+
END;
197+
198+
$f$ LANGUAGE plpgsql VOLATILE ;
199+
200+
201+
202+
DO $f$
203+
BEGIN
204+
ASSERT (SELECT true = null::json_schema_validation_result::bool);
205+
ASSERT (SELECT true = (null)::json_schema_validation_result::bool);
206+
ASSERT (SELECT true = (null, null)::json_schema_validation_result::bool);
207+
ASSERT (SELECT true = ('{path,to,field}', null)::json_schema_validation_result::bool);
208+
209+
ASSERT ( SELECT result FROM test_raises_exception( $$ SELECT true = null::json_schema_validation_result $$, '{"message_text": "operator does not exist: boolean = json_schema_validation_result"}' ) );
210+
ASSERT ( SELECT result FROM test_raises_exception( $$ SELECT true = ARRAY[(null)::json_schema_validation_result] $$, '{"message_text": "operator does not exist: boolean = json_schema_validation_result[]"}' ) );
211+
212+
ASSERT (SELECT NOT (NOT NULL::json_schema_validation_result));
213+
ASSERT (SELECT NOT (NOT NULL::json_schema_validation_result));
214+
ASSERT (SELECT NOT ('{path,to,field}', 'FAILED')::json_schema_validation_result);
215+
ASSERT (SELECT NOT ARRAY[('{path,to,field}', 'FAILED')]::json_schema_validation_result[]);
216+
ASSERT (SELECT NOT ARRAY[('{path,to,field}', 'FAILED')]::json_schema_validation_result[]);
217+
ASSERT (SELECT NOT ARRAY[NULL, ('{path,to,field}', 'FAILED')]::json_schema_validation_result[]);
218+
ASSERT (SELECT ARRAY[NULL]::json_schema_validation_result[]);
219+
ASSERT (SELECT ARRAY[('{path,to,field}', null)]::json_schema_validation_result[]::bool);
220+
ASSERT (SELECT NULL::json_schema_validation_result[]::bool);
221+
222+
END;
223+
$f$;
224+
225+
226+
DO $f$
227+
DECLARE
228+
v_result RECORD;
229+
v_schema1 jsonb := $$ {
230+
"definitions": {
231+
"reffed": {
232+
"type": "array"
233+
}
234+
},
235+
"properties": {
236+
"foo": {
237+
"$ref": "#/definitions/reffed",
238+
"maxItems": 2
239+
}
240+
}
241+
} $$;
242+
243+
v_schema2 jsonb := $${
244+
"definitions": {
245+
"reffed": {
246+
"type": "array"
247+
}
248+
},
249+
"properties": {
250+
"foo": {
251+
"type": "array",
252+
"maxItems": 2,
253+
"items": {
254+
"type": "number"
255+
}
256+
}
257+
}
258+
} $$;
259+
BEGIN
260+
261+
SELECT INTO v_result *, ARRAY[('{foo}','string is not a valid type: {array}')]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations(v_schema1, $$ { "foo": "string" } $$) a;
262+
ASSERT v_result.valid, v_result;
263+
SELECT INTO v_result *, ARRAY[('{foo}','items count of 3 exceeds maxItems of 2')]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations(v_schema1, $$ { "foo": ["string", "23", 1] } $$) a;
264+
ASSERT v_result.valid, v_result;
265+
SELECT INTO v_result *, ARRAY[]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations(v_schema1, $$ { "foo": ["string", 1] } $$) a;
266+
ASSERT v_result.valid, v_result;
267+
SELECT INTO v_result *, ARRAY[('{1}','string is not a valid type: {integer}')]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations('{"items": [{"type": "integer"}, {"$ref": "#/items/0"}]}', '[1, "foo"]') a;
268+
ASSERT v_result.valid, v_result;
269+
SELECT INTO v_result *, ARRAY[('{foo,0}','string is not a valid type: {number}')]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations(v_schema2, $$ { "foo": ["hello"] } $$) a;
270+
ASSERT v_result.valid, v_result;
271+
-- test string is not valid even if it is all digits when string_as_number is false
272+
SELECT INTO v_result *, ARRAY[('{foo,0}','string is not a valid type: {number}')]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations(v_schema2, $$ { "foo": ["0"] } $$) a;
273+
ASSERT v_result.valid, v_result;
274+
-- test quoted number is valid when string_as_number is true with a literal string
275+
SELECT INTO v_result *, ARRAY[]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations('{"type": "number"}', $$"1"$$, true) a;
276+
ASSERT v_result.valid, v_result;
277+
-- test quoted number is valid when string_as_number is true with a literal decimal string
278+
SELECT INTO v_result *, ARRAY[]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations('{"type": "number"}', $$"1.1"$$, true) a;
279+
ASSERT v_result.valid, v_result;
280+
-- test quoted number is valid when string_as_number is true with an object
281+
SELECT INTO v_result *, ARRAY[]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations('{"properties": {"foo": {"type": "number"}}}', $${ "foo": "1" }$$, true) a;
282+
ASSERT v_result.valid, v_result;
283+
-- test quoted number is valid when string_as_number is true with an array
284+
SELECT INTO v_result *, ARRAY[]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations(v_schema2, $$ { "foo": ["0"] } $$, true) a;
285+
ASSERT v_result.valid, v_result;
286+
287+
-- test quoted number when string_as_number is true with a invalid numerical string
288+
SELECT INTO v_result *, ARRAY[('{}', 'string is not a valid type: {number}')]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations('{"type": "number"}', $$".1"$$, true) a;
289+
ASSERT v_result.valid, v_result;
290+
291+
-- test quoted number when string_as_number is true with a invalid numerical string
292+
SELECT INTO v_result *, ARRAY[('{}', 'string is not a valid type: {number}')]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations('{"type": "number"}', $$"0.1.1"$$, true) a;
293+
ASSERT v_result.valid, v_result;
294+
295+
-- test quoted integer is not valid even when string_as_number is true
296+
SELECT INTO v_result *, ARRAY[('{1}','string is not a valid type: {integer}')]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations('{"items": [{"type": "integer"}, {"$ref": "#/items/0"}]}', '[1, "1"]', true) a;
297+
ASSERT v_result.valid, v_result;
298+
299+
v_result := test_raises_exception(format($$ SELECT json_schema_check_constraint (%L, '{ "foo": ["string", 1, "Too many items here"] }') $$, v_schema1), '{"message_text": "json_schema_validation_failed", "PG_EXCEPTION_DETAIL": [{"path": ["foo"], "error": "items count of 3 exceeds maxItems of 2"}]}');
300+
ASSERT v_result.result = true, v_result;
301+
-- does not raise any exception for valid string
302+
ASSERT true = json_schema_check_constraint('{"type": "number"}', '"1.9"', true);
303+
304+
-- create the table
305+
EXECUTE format($$ CREATE TEMPORARY TABLE test_entry (data jsonb CHECK ( validate_json_schema(%L, data) )) ON COMMIT DROP$$, v_schema1);
306+
-- valid data
307+
INSERT INTO test_entry VALUES ('{ "foo": ["string", 1] }');
308+
-- invalid data
309+
v_result := test_raises_exception($$ INSERT INTO test_entry VALUES ('{ "foo": ["string", 1, "Too many items here"] }') $$, '{"message_text": "new row for relation \"test_entry\" violates check constraint \"test_entry_data_check\""}');
310+
ASSERT v_result.result = true, v_result;
311+
312+
-- Create the table
313+
EXECUTE format($$ CREATE TEMPORARY TABLE test_entry_with_detailed_message (data jsonb CHECK ( json_schema_check_constraint(%L, data) )) ON COMMIT DROP$$, v_schema1);
314+
-- test valid data
315+
INSERT INTO test_entry_with_detailed_message VALUES ('{ "foo": ["string", 1] }');
316+
-- test invalid data
317+
318+
v_result := test_raises_exception($$ INSERT INTO test_entry_with_detailed_message VALUES ('{ "foo": ["string", 1, "Too many items here"] }') $$, '{"message_text": "json_schema_validation_failed", "PG_EXCEPTION_DETAIL": [{"path": ["foo"], "error": "items count of 3 exceeds maxItems of 2"}] }' );
319+
ASSERT v_result.result = true, v_result;
320+
321+
END
322+
$f$;

0 commit comments

Comments
 (0)