diff --git a/JSON-Schema-Test-Suite b/JSON-Schema-Test-Suite index 5fb3d9f..2782d7c 160000 --- a/JSON-Schema-Test-Suite +++ b/JSON-Schema-Test-Suite @@ -1 +1 @@ -Subproject commit 5fb3d9f1a1c4136f544fbd0029942ea559732f8e +Subproject commit 2782d7c296f9f828e09c8a2878b0035b2c371a2a diff --git a/Makefile b/Makefile index 52ea8ab..0cc461e 100644 --- a/Makefile +++ b/Makefile @@ -1,5 +1,5 @@ EXTENSION = postgres-json-schema -DATA = postgres-json-schema--0.1.1.sql +DATA = postgres-json-schema--0.1.1.sql postgres-json-schema--0.2.0.sql # postgres build stuff PG_CONFIG = pg_config diff --git a/README.md b/README.md index c5bda52..4927bd7 100644 --- a/README.md +++ b/README.md @@ -7,7 +7,7 @@ schemas](http://json-schema.org/) in PostgreSQL. It is implemented as a PL/pgSQL function and you can use it as a check constraint to validate the format of your JSON columns. -postgres-json-schema supports the entire JSON schema draft v4 spec, except for +postgres-json-schema supports the entire JSON schema draft v4 and v7 spec, except for remote (http) references. It's tested against the official [JSON-Schema-Test-Suite](https://github.com/json-schema-org/JSON-Schema-Test-Suite). @@ -17,14 +17,85 @@ postgres-json-schema is packaged as an PGXS extension. To install, just run `make install` as root, then `CREATE EXTENSION "postgres-json-schema";` as the database superuser. +# Usage + +## Types +- `json_schema_validation_result` A composite type which contains error messages and path (an array to the path) within json data where the validation failed + #### contains the following attributes + - `path` a `text[]` to the path where the validation failed + - `error` the validation error message + +## Functions + +#### Functions accepting a argument `string_as_number` controlling whether a schema expecting a number may contain a valid number as a string. This is useful when dealing with for example python Decimal, which most implementations serialize it to json as a quoted string not to lose decimal precision. + +- ```sql + -- Returns bool + validate_json_schema(schema jsonb, data jsonb, string_as_number bool) + ``` +- ```sql + -- Returns ARRAY json_schema_validation_result[] + get_json_schema_validations(schema jsonb, data jsonb, string_as_number bool) + ``` +- ```sql + -- Returns true if valid, + -- otherwise raises a check_constraint exception, this is useful when you want to get a detailed + -- error knowing which part of the json document failed to validate. + json_schema_check_constraint( + schema jsonb, + data jsonb, + string_as_number bool default false, + table_name text default '', -- if you need to set the value for TABLE in the PG_EXCEPTION_CONTEXT + column_name text default '' -- if you need to set the value for COLUMN in the PG_EXCEPTION_CONTEXT + ) + ``` +- `json_schema_resolve_refs( schema )` + + When dealing with a JSON schema that has `$id` uri values being used in `$ref`, + there is a convenient function to resolve those references + ```sql + validate_json_schema( json_schema_resolve_refs( schema ), data ); + -- or + json_schema_check_constraint( json_schema_resolve_refs( schema ), data, ... ); + ``` + + # Example - CREATE TABLE example (id serial PRIMARY KEY, data jsonb); - ALTER TABLE example ADD CONSTRAINT data_is_valid CHECK (validate_json_schema('{"type": "object"}', data)); +#### Using standard default check constraint with boolean function +```sql +CREATE TABLE example (id serial PRIMARY KEY, data jsonb); +ALTER TABLE example ADD CONSTRAINT data_is_valid CHECK (validate_json_schema('{"type": "object"}', data)); + +INSERT INTO example (data) VALUES ('{}'); +-- INSERT 0 1 + +INSERT INTO example (data) VALUES ('1'); +-- ERROR: new row for relation "example" violates check constraint "data_is_valid" +-- DETAIL: Failing row contains (2, 1). +``` + + +#### Using custom check constraint exception with detailed error +```sql +CREATE TABLE example (id serial PRIMARY KEY, data jsonb); +ALTER TABLE example ADD CONSTRAINT data_is_valid CHECK (json_schema_check_constraint('{"type": "object", "properties": { "foo": {"type": "number"}, "bar": { "prefixItems": [{ "type": "number" }, { "type": "number", "minimum": 2 }] } }}', data, true, table_name := 'example', column_name := 'data')); + +INSERT INTO example (data) VALUES ('{}'); +-- INSERT 0 1 + +INSERT INTO example (data) VALUES ('1'); +-- ERROR: json_schema_validation_failed +-- DETAIL: [{"path": [], "error": "number is not a valid type: {object}"}] +-- CONTEXT: PL/pgSQL function json_schema_check_constraint(jsonb,jsonb,boolean,text,text) line 7 at RAISE - INSERT INTO example (data) VALUES ('{}'); - -- INSERT 0 1 +INSERT INTO example (data) VALUES ('{ "foo": "string" }'); +-- ERROR: json_schema_validation_failed +-- DETAIL: [{"path": ["foo"], "error": "string is not a valid type: {number}"}] +-- CONTEXT: PL/pgSQL function json_schema_check_constraint(jsonb,jsonb,boolean,text,text) line 7 at RAISE - INSERT INTO example (data) VALUES ('1'); - -- ERROR: new row for relation "example" violates check constraint "data_is_valid" - -- DETAIL: Failing row contains (2, 1). +INSERT INTO example (data) VALUES ('{ "foo": 1, "bar": ["a", 1.1] }'); +-- ERROR: json_schema_validation_failed +-- DETAIL: [{"path": ["bar", "0"], "error": "string is not a valid type: {number}"}, {"path": ["bar", "1"], "error": "value must be >= 2"}] +-- CONTEXT: PL/pgSQL function json_schema_check_constraint(jsonb,jsonb,boolean,text,text) line 7 at RAISE +``` diff --git a/postgres-json-schema--0.2.0.sql b/postgres-json-schema--0.2.0.sql new file mode 100644 index 0000000..10e94aa --- /dev/null +++ b/postgres-json-schema--0.2.0.sql @@ -0,0 +1,731 @@ +CREATE TYPE json_schema_validation_result AS ( + path text[], + error text +); + + +CREATE OR REPLACE FUNCTION json_schema_validation_result_as_bool (@extschema@.json_schema_validation_result) RETURNS bool AS $$ + SELECT ($1).error IS NULL; +$$ LANGUAGE SQL IMMUTABLE; + +CREATE CAST ( json_schema_validation_result AS bool ) + WITH FUNCTION @extschema@.json_schema_validation_result_as_bool(json_schema_validation_result) + AS ASSIGNMENT; + +CREATE OR REPLACE FUNCTION json_schema_validation_result_array_as_bool (@extschema@.json_schema_validation_result[]) RETURNS bool AS $$ + SELECT $1 IS NULL OR true = ALL ($1::bool[]); +$$ LANGUAGE SQL IMMUTABLE; + + +CREATE CAST ( json_schema_validation_result[] AS bool ) + WITH FUNCTION @extschema@.json_schema_validation_result_array_as_bool(json_schema_validation_result[]) + AS ASSIGNMENT; + + + +CREATE OR REPLACE FUNCTION urldecode_arr(url text) RETURNS text AS $BODY$ + DECLARE + ret text; + BEGIN + BEGIN + WITH str AS ( + SELECT + -- array with all non encoded parts, prepend with '' when the string start is encoded + CASE WHEN $1 ~ '^%[0-9a-fA-F][0-9a-fA-F]' THEN + ARRAY [''] + END || regexp_split_to_array($1, '(%[0-9a-fA-F][0-9a-fA-F])+', 'i') plain, + + -- array with all encoded parts + ARRAY(select (regexp_matches($1, '((?:%[0-9a-fA-F][0-9a-fA-F])+)', 'gi'))[1]) encoded + ) + SELECT string_agg(plain[i] || coalesce(convert_from(decode(replace(encoded[i], '%', ''), 'hex'), 'utf8'), ''), '') + FROM str, (SELECT generate_series(1, array_upper(encoded, 1) + 2) i FROM str) blah + INTO ret; + + EXCEPTION + WHEN OTHERS THEN + RAISE NOTICE 'failed: %', url; + RETURN $1; + END; + + RETURN coalesce(ret, $1); -- when the string has no encoding; + + END; +$BODY$ LANGUAGE plpgsql IMMUTABLE STRICT; + + +CREATE OR REPLACE FUNCTION _validate_json_schema_type(type text, data jsonb, string_as_number bool default false) RETURNS boolean AS $f$ +BEGIN + IF type = 'integer' THEN + IF jsonb_typeof(data) != 'number' THEN + RETURN false; + END IF; + IF trunc(data::text::numeric) != data::text::numeric THEN + RETURN false; + END IF; + ELSEIF type = 'number' AND jsonb_typeof(data) = 'string' THEN + IF NOT string_as_number OR NOT data @? '$ ? (@ like_regex "^\\d+(\\.\\d+)?$")'::jsonpath THEN + RETURN false; + END IF; + ELSE + IF type != jsonb_typeof(data) THEN + RETURN false; + END IF; + END IF; + RETURN true; +END; +$f$ LANGUAGE 'plpgsql' IMMUTABLE; + + +-- MOCK Placeholder +CREATE OR REPLACE FUNCTION get_json_schema_validations(schema jsonb, data jsonb, root_schema jsonb, schema_path text[], string_as_number bool) +RETURNS @extschema@.json_schema_validation_result[] AS $f$ BEGIN END; $f$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION get_json_schema_validations(schema jsonb, data jsonb, string_as_number bool DEFAULT false) +RETURNS @extschema@.json_schema_validation_result[] AS $f$ + SELECT @extschema@.get_json_schema_validations(schema, data, schema, ARRAY []::text[], string_as_number); +$f$ LANGUAGE SQL IMMUTABLE ; + +CREATE OR REPLACE FUNCTION validate_json_schema(schema jsonb, data jsonb, string_as_number bool) RETURNS bool AS $f$ + SELECT @extschema@.get_json_schema_validations(schema, data, schema, ARRAY []::text[], string_as_number)::bool; +$f$ LANGUAGE SQL IMMUTABLE ; + +CREATE OR REPLACE FUNCTION validate_json_schema(schema jsonb, data jsonb, root_schema jsonb DEFAULT null, string_as_number bool DEFAULT false) RETURNS bool AS $f$ + SELECT @extschema@.get_json_schema_validations(schema, data, root_schema, ARRAY []::text[], string_as_number)::bool; +$f$ LANGUAGE SQL IMMUTABLE ; + +CREATE OR REPLACE FUNCTION json_schema_check_constraint( + schema jsonb, + data jsonb, + string_as_number bool default false, + table_name text default '', + column_name text default '' +) RETURNS bool AS $$ + DECLARE + result @extschema@.json_schema_validation_result[]; + BEGIN + result := @extschema@.get_json_schema_validations(schema, data, schema, '{}'::text[], string_as_number := string_as_number); + IF (NOT result) THEN + RAISE check_violation USING + MESSAGE = 'json_schema_validation_failed', + DETAIL = to_jsonb(result), + -- HINT = v_value, + TABLE = table_name, + COLUMN = column_name; + END IF; + RETURN true; + END; +$$ LANGUAGE plpgsql IMMUTABLE ; + + + +CREATE OR REPLACE FUNCTION _validate_json_multiple_schemas( + schemas_array jsonb, data jsonb, root_schema jsonb, schema_path text[], string_as_number bool, + OUT validation_booleans bool[], + OUT all_errors @extschema@.json_schema_validation_result[] +) AS $f$ + WITH schema_validations AS ( + SELECT q FROM jsonb_array_elements(schemas_array) sub_schema, + @extschema@.get_json_schema_validations(sub_schema, data, root_schema, schema_path, string_as_number) q + ) + SELECT + (SELECT array_agg(q::bool) FROM schema_validations t(q)) AS validation_booleans, + (SELECT array_agg(v) FILTER ( WHERE NOT v) FROM schema_validations t(q), unnest(q) v) AS all_errors +$f$ LANGUAGE SQL IMMUTABLE ; + + +CREATE OR REPLACE FUNCTION get_json_schema_validations(schema jsonb, data jsonb, root_schema jsonb, schema_path text[], string_as_number bool) +RETURNS @extschema@.json_schema_validation_result[] AS $f$ +DECLARE + prop text; + item jsonb; + idx int; + path text[]; + types text[]; + prefixItems jsonb; + additionalItems jsonb; + pattern text; + props text[]; + result @extschema@.json_schema_validation_result[]; + q_result record; +BEGIN + IF root_schema IS NULL THEN + root_schema = schema; + END IF; + + IF schema IS NULL THEN + RETURN ARRAY [(schema_path, format('NULL schema: [data: %s]', data))]; + END IF; + + IF jsonb_typeof(schema) = 'boolean' THEN + IF schema = 'true'::jsonb THEN + RETURN NULL; -- anything is valid + ELSEIF schema = 'false'::jsonb THEN + RETURN ARRAY [(schema_path, format('"false" does not accept any value received "%s"', data))]; -- anything is valid + ELSEIF schema != data THEN + RETURN ARRAY [(schema_path, format('%s does not match %s', data, schema))]; + END IF; + END IF; + + IF schema ? 'type' THEN + IF jsonb_typeof(schema->'type') = 'array' THEN + types = ARRAY(SELECT jsonb_array_elements_text(schema->'type')); + ELSE + types = ARRAY[schema->>'type']; + END IF; + IF (SELECT NOT bool_or(@extschema@._validate_json_schema_type(type, data, string_as_number)) FROM unnest(types) type) THEN + RETURN ARRAY [(schema_path, format('%s is not a valid type: %s', jsonb_typeof(data), types))]; + END IF; + END IF; + + IF schema ? 'properties' THEN + FOR prop IN SELECT jsonb_object_keys(schema->'properties') LOOP + IF data ? prop THEN + result := @extschema@.get_json_schema_validations(schema->'properties'->prop, data->prop, root_schema, schema_path || prop, string_as_number); + IF NOT result THEN + RETURN result; + END IF; + END IF; + END LOOP; + END IF; + + IF schema ? 'required' AND jsonb_typeof(data) = 'object' THEN + IF NOT ARRAY(SELECT jsonb_object_keys(data)) @> + ARRAY(SELECT jsonb_array_elements_text(schema->'required')) THEN + RETURN ARRAY [(schema_path, format('%s is missing required properties: %s', schema->>'type', ARRAY( + SELECT jsonb_array_elements_text(schema->'required') + EXCEPT + SELECT jsonb_object_keys(data) + )))]; + END IF; + END IF; + + /* + In 2019 items could be any of [boolean, object] + In draft6 items could be [boolean, object, array] + In draft4 items could be either a [object, array] + */ + IF jsonb_typeof(data) = 'array' THEN + IF schema ? 'prefixItems' THEN + -- jsonschema 2019 + prefixItems := schema->'prefixItems'; + IF schema ? 'items' THEN + additionalItems := schema->'items'; + ELSEIF schema ? 'additionalItems' THEN + additionalItems := schema->'additionalItems'; + END IF; + ELSEIF schema ? 'items' THEN + IF jsonb_typeof(schema->'items') = 'object' THEN + additionalItems := schema->'items'; + ELSEIF jsonb_typeof(schema->'items') = 'array' THEN + prefixItems := schema->'items'; + additionalItems := schema->'additionalItems'; + ELSEIF jsonb_typeof(schema->'items') = 'boolean' THEN + additionalItems := schema->'items'; + END IF; + END IF; + + IF prefixItems IS NOT NULL THEN + SELECT array_agg(q) INTO result + FROM jsonb_array_elements(prefixItems) WITH ORDINALITY AS t(sub_schema, i), + @extschema@.get_json_schema_validations(sub_schema, data->(i::int - 1), root_schema, schema_path || (i - 1)::text, string_as_number) q1, unnest(q1) q + WHERE i <= jsonb_array_length(data); + IF NOT result THEN + RETURN result; + END IF; + + END IF; + + IF jsonb_typeof(additionalItems) = 'boolean' and NOT (additionalItems)::text::boolean THEN + IF jsonb_array_length(data) > COALESCE(jsonb_array_length(prefixItems), 0) THEN + RETURN ARRAY [(schema_path, format('field only accepts %s items', COALESCE(jsonb_array_length(prefixItems), 0)))]; + END IF; + END IF; + + IF jsonb_typeof(additionalItems) = 'object' THEN + SELECT array_agg(q) INTO result + FROM jsonb_array_elements(data) WITH ORDINALITY AS t(elem, i), + @extschema@.get_json_schema_validations(additionalItems, elem, root_schema, schema_path || (i - 1)::text, string_as_number) AS q1, unnest(q1) q + WHERE i > coalesce(jsonb_array_length(prefixItems), 0) AND NOT q LIMIT 1; + + IF NOT result THEN + RETURN result; + END IF; + END IF; + END IF; + + + IF schema ? 'minimum' AND jsonb_typeof(data) = 'number' THEN + IF data::text::numeric < (schema->>'minimum')::numeric THEN + RETURN ARRAY [(schema_path, format('value must be >= %s', (schema->>'minimum')))]; + END IF; + END IF; + + IF schema ? 'maximum' AND jsonb_typeof(data) = 'number' THEN + IF data::text::numeric > (schema->>'maximum')::numeric THEN + RETURN ARRAY [(schema_path, format('value must be <= %s', (schema->>'maximum')))]; + END IF; + END IF; + + IF schema ? 'exclusiveMinimum' AND jsonb_typeof(data) = 'number' THEN + IF jsonb_typeof(schema->'exclusiveMinimum') = 'number' THEN + IF data::text::numeric <= (schema->>'exclusiveMinimum')::numeric THEN + RETURN ARRAY [(schema_path, format('value must be > %s', (schema->>'exclusiveMinimum')))]; + END IF; + ELSEIF COALESCE((schema->'exclusiveMinimum')::text::bool, FALSE) THEN + IF data::text::numeric = (schema->>'minimum')::numeric THEN + RETURN ARRAY [(schema_path, format('value must be > %s', (schema->>'minimum')))]; + END IF; + END IF; + END IF; + + IF schema ? 'exclusiveMaximum' AND jsonb_typeof(data) = 'number' THEN + IF jsonb_typeof(schema->'exclusiveMaximum') = 'number' THEN + IF data::text::numeric >= (schema->>'exclusiveMaximum')::numeric THEN + RETURN ARRAY [(schema_path, format('value must be < %s', (schema->>'exclusiveMinimum')))]; + END IF; + ELSEIF COALESCE((schema->'exclusiveMaximum')::text::bool, FALSE) THEN + IF data::text::numeric = (schema->>'maximum')::numeric THEN + RETURN ARRAY [(schema_path, format('value must be < %s', (schema->>'maximum')))]; + END IF; + END IF; + END IF; + + IF schema ? 'anyOf' THEN + q_result := @extschema@._validate_json_multiple_schemas(schema->'anyOf', data, root_schema, schema_path, string_as_number); + IF NOT (SELECT true = any (q_result.validation_booleans)) THEN + RETURN q_result.all_errors || (schema_path, 'does not match any of the required schemas')::@extschema@.json_schema_validation_result; + END IF; + END IF; + + IF schema ? 'allOf' THEN + q_result := @extschema@._validate_json_multiple_schemas(schema->'allOf', data, root_schema, schema_path, string_as_number); + IF NOT (SELECT true = all(q_result.validation_booleans)) THEN + RETURN q_result.all_errors || (schema_path, 'does not match all of the required schemas')::@extschema@.json_schema_validation_result; + END IF; + END IF; + + IF schema ? 'oneOf' THEN + q_result := @extschema@._validate_json_multiple_schemas(schema->'oneOf', data, root_schema, schema_path, string_as_number); + SELECT count(a::bool) INTO idx FROM unnest(q_result.validation_booleans) a WHERE a = true; + IF (idx != 1) THEN + RETURN ARRAY [(schema_path, format('should match exactly one of the schemas, but matches %s', idx))::@extschema@.json_schema_validation_result]; + END IF; + END IF; + + IF COALESCE((schema->'uniqueItems')::text::boolean, false) THEN + IF (SELECT COUNT(*) FROM jsonb_array_elements(data)) != (SELECT count(DISTINCT val) FROM jsonb_array_elements(data) val) THEN + RETURN ARRAY [(schema_path, 'field has duplicates')]; + END IF; + END IF; + + IF schema ? 'additionalProperties' AND jsonb_typeof(data) = 'object' THEN + props := ARRAY( + SELECT key + FROM jsonb_object_keys(data) key + WHERE key NOT IN (SELECT jsonb_object_keys(schema->'properties')) + AND NOT EXISTS (SELECT * FROM jsonb_object_keys(schema->'patternProperties') pat WHERE key ~ pat) + ); + IF jsonb_typeof(schema->'additionalProperties') = 'boolean' THEN + IF NOT (schema->'additionalProperties')::text::boolean AND jsonb_typeof(data) = 'object' AND array_length(props, 1) > 0 THEN + RETURN ARRAY [(schema_path, format('additionalProperties %s not allowed', props))]; + END IF; + ELSE + SELECT array_agg(q) INTO result FROM unnest(props) key, @extschema@.get_json_schema_validations(schema->'additionalProperties', data->key, root_schema, schema_path || key, string_as_number) q1, unnest(q1) q; + IF NOT (true = all(result::bool[])) THEN + RETURN result; + END IF; + END IF; + END IF; + + IF schema ? '$ref' THEN + IF schema ? '$_resolvedRef' THEN + path := ARRAY( SELECT jsonb_array_elements_text(schema->'$_resolvedRef') ); + ELSE + -- ASSERT path[1] = '#', 'only refs anchored at the root are supported'; + path := @extschema@.json_schema_resolve_ref(schema->>'$ref', NULL, NULL, NULL); + END IF; + + IF path IS NULL THEN + RETURN ARRAY [(schema_path, format('$ref %s does not exist', schema->>'$ref'))]; + END IF; + + result := @extschema@.get_json_schema_validations(root_schema #> path, data, root_schema, schema_path, string_as_number); + IF NOT (true = all(result::bool[])) THEN + RETURN result; + END IF; + END IF; + + IF schema ? 'enum' THEN + IF NOT EXISTS (SELECT * FROM jsonb_array_elements(schema->'enum') val WHERE val = data) THEN + RETURN ARRAY [(schema_path, format('%s is an invalid enum value: %s', data, schema->'enum'))]; + END IF; + END IF; + + IF schema ? 'const' THEN + IF data != schema->'const' THEN + RETURN ARRAY [(schema_path, format('value doe snot match const: %s', data, schema->'const'))]; + END IF; + END IF; + + IF schema ? 'contains' AND jsonb_typeof(data) = 'array' THEN + IF jsonb_array_length(data) < 1 THEN + RETURN ARRAY [(schema_path, format('empty array does not have any items matching schema %s', schema->>'contains'))]; + END IF; + SELECT array_agg(q::bool) AS a INTO q_result FROM jsonb_array_elements(data) WITH ORDINALITY t(elem, i), + @extschema@.get_json_schema_validations(schema->'contains', elem, root_schema, schema_path || (i - 1)::text, string_as_number) q; + IF false = ALL(q_result.a) THEN + RETURN ARRAY [(schema_path, format('array does not contain any items matching schema %s', schema->>'contains'))]; + END IF; + END IF; + + IF schema ? 'minLength' AND jsonb_typeof(data) = 'string' THEN + IF char_length(data #>> '{}') < (schema->>'minLength')::numeric THEN + RETURN ARRAY [(schema_path, format('field must be at least %s long', schema->>'minLength'))]; + END IF; + END IF; + + IF schema ? 'maxLength' AND jsonb_typeof(data) = 'string' THEN + IF char_length(data #>> '{}') > (schema->>'maxLength')::numeric THEN + RETURN ARRAY [(schema_path, format('field may not be longer than %s', schema->>'maxLength'))]; + END IF; + END IF; + + IF schema ? 'not' THEN + result := @extschema@.get_json_schema_validations(schema->'not', data, root_schema, schema_path, string_as_number); + IF (result) THEN + RETURN ARRAY [(schema_path, format('field must not be any of %s', schema->'not'))]; + END IF; + END IF; + + IF schema ? 'maxProperties' AND jsonb_typeof(data) = 'object' THEN + SELECT count(*) INTO idx FROM jsonb_object_keys(data); + IF idx > (schema->>'maxProperties')::numeric THEN + RETURN ARRAY [(schema_path, format('field properties count %s exceeds maxProperties of %s', idx, schema->'maxProperties'))]; + END IF; + END IF; + + IF schema ? 'minProperties' AND jsonb_typeof(data) = 'object' THEN + SELECT count(*) INTO idx FROM jsonb_object_keys(data); + IF idx < (schema->>'minProperties')::numeric THEN + RETURN ARRAY [(schema_path, format('field properties count %s is less than minProperties of %s', idx, schema->'minProperties'))]; + END IF; + END IF; + + IF schema ? 'maxItems' AND jsonb_typeof(data) = 'array' THEN + SELECT count(*) INTO idx FROM jsonb_array_elements(data); + IF idx > (schema->>'maxItems')::numeric THEN + RETURN ARRAY [(schema_path, format('items count of %s exceeds maxItems of %s', idx, schema->'maxItems'))]; + END IF; + END IF; + + IF schema ? 'minItems' AND jsonb_typeof(data) = 'array' THEN + SELECT count(*) INTO idx FROM jsonb_array_elements(data); + IF idx < (schema->>'minItems')::numeric THEN + RETURN ARRAY [(schema_path, format('items count of %s is less than minItems of %s', idx, schema->'minItems'))]; + END IF; + END IF; + + IF schema ? 'dependencies' AND jsonb_typeof(data) != 'array' THEN + FOR prop IN SELECT jsonb_object_keys(schema->'dependencies') LOOP + IF data ? prop THEN + IF jsonb_typeof(schema->'dependencies'->prop) = 'array' THEN + SELECT array_agg(dep) INTO props FROM jsonb_array_elements_text(schema->'dependencies'->prop) dep WHERE NOT data ? dep; + IF (array_length(props, 1) > 0) THEN + RETURN ARRAY [(schema_path || prop, format('missing required dependencies %s', props))]; + END IF; + ELSE + result := @extschema@.get_json_schema_validations(schema->'dependencies'->prop, data, root_schema, schema_path, string_as_number); + IF NOT result THEN + RETURN result; + END IF; + END IF; + END IF; + END LOOP; + END IF; + + IF schema ? 'pattern' AND jsonb_typeof(data) = 'string' THEN + IF (data #>> '{}') !~ (schema->>'pattern') THEN + RETURN ARRAY [(schema_path, format('field does not match pattern %s', schema->>'pattern'))]; + END IF; + END IF; + + IF schema ? 'patternProperties' AND jsonb_typeof(data) = 'object' THEN + FOR prop IN SELECT jsonb_object_keys(data) LOOP + FOR pattern IN SELECT jsonb_object_keys(schema->'patternProperties') LOOP + IF prop ~ pattern AND NOT @extschema@.get_json_schema_validations(schema->'patternProperties'->pattern, data->prop, root_schema, schema_path, string_as_number) THEN + RETURN ARRAY [(schema_path || prop, format('field does not match pattern %s', pattern))]; + END IF; + END LOOP; + END LOOP; + END IF; + + IF schema ? 'multipleOf' AND jsonb_typeof(data) = 'number' THEN + IF data::text::numeric % (schema->>'multipleOf')::numeric != 0 THEN + RETURN ARRAY [(schema_path, format('value must be a multiple of %s', schema->>'multipleOf'))]; + END IF; + END IF; + + + IF schema ? 'propertyNames' AND jsonb_typeof(data) = 'object' THEN + result := ARRAY( SELECT v FROM jsonb_object_keys(data) propName, @extschema@.get_json_schema_validations(schema->'propertyNames', to_jsonb(propName), root_schema, schema_path || propName, string_as_number) v WHERE not v); + IF NOT result THEN + RETURN result; + END IF; + END IF; + + + IF schema ? 'if' AND (schema ? 'then' OR schema ? 'else') THEN + result := @extschema@.get_json_schema_validations(schema->'if', data, root_schema, schema_path || 'if'::text, string_as_number); + IF result AND schema ? 'then' THEN + result := @extschema@.get_json_schema_validations(schema->'then', data, root_schema, schema_path || 'then'::text, string_as_number); + ELSEIF NOT result AND schema ? 'else' THEN + result := @extschema@.get_json_schema_validations(schema->'else', data, root_schema, schema_path || 'else'::text, string_as_number); + ELSE + result := NULL; + END IF; + + IF NOT result THEN + RETURN result; + END IF; + END IF; + + RETURN '{}'::@extschema@.json_schema_validation_result[]; +END; +$f$ LANGUAGE 'plpgsql' VOLATILE ; + + +CREATE OR REPLACE FUNCTION json_schema_resolve_uri( + to_resolve text, + OUT resolved_uri text, + IN OUT base_uri text default null, + IN OUT base_path text default null + ) +RETURNS RECORD AS $f$ + DECLARE + v_parts text[]; + v_path text; + BEGIN + IF to_resolve LIKE 'urn:%' THEN + + IF to_resolve LIKE '%#%' THEN + v_parts = string_to_array(to_resolve, '#'); + base_uri := v_parts[1]; + base_path := ''; + resolved_uri := base_uri || '#' || v_parts[2]; + ELSE + base_uri := to_resolve; + base_path := ''; + resolved_uri := to_resolve; + END IF; + RETURN; + + ELSEIF to_resolve LIKE '%://%' THEN + v_parts := string_to_array(to_resolve, '/'); + IF base_uri IS NULL THEN + base_uri := v_parts[1] || '//' || v_parts[3]; + END IF; + v_path := '/' || array_to_string(v_parts[4:], '/'); + ELSE + v_path := to_resolve; + END IF; + + IF v_path LIKE '/%' THEN + base_path := v_path; + ELSE + IF v_path LIKE '#%' OR base_path LIKE '%/' THEN + base_path := coalesce(base_path, '') || v_path; + ELSEIF base_path IS NOT NULL THEN + v_parts := string_to_array(base_path, '/'); + base_path := array_to_string( v_parts[ 1 : array_length(v_parts, 1) - 1], '/' ) || '/' || v_path; + ELSE + base_path := '/' || v_path; + END IF; + END IF; + resolved_uri := coalesce(base_uri, '') || base_path; + END; +$f$ LANGUAGE plpgsql IMMUTABLE; + + +CREATE OR REPLACE FUNCTION json_schema_resolve_refs( + IN OUT schema jsonb, + base_uri text, + base_path text, + resolved_ids_mapping jsonb, + resolve_refs bool +) AS $f$ + DECLARE + id text; + sub_schema jsonb; + resolved_path text[]; + resolved_uri text; + key text; + idx int; + BEGIN + IF resolve_refs THEN + IF schema ? '$ref' THEN + resolved_path := (@extschema@.json_schema_resolve_ref(schema->>'$ref', base_uri, base_path, resolved_ids_mapping)); + schema := jsonb_set(schema, ARRAY['$_resolvedRef'], to_jsonb(resolved_path)); + END IF; + + IF schema ? 'id' THEN + id := schema->>'id'; + ELSEIF schema ? '$id' THEN + id := schema->>'$id'; + END IF; + IF id IS NOT NULL THEN + SELECT t.resolved_uri, t.base_uri, t.base_path + INTO resolved_uri, base_uri, base_path + FROM @extschema@.json_schema_resolve_uri(id, base_uri, base_path) t; + END IF; + END IF; + + IF jsonb_typeof(schema) = 'object' THEN + FOR key, sub_schema IN SELECT t.key, schema->(t.key) FROM jsonb_object_keys(schema) t(key) WHERE t.key NOT IN ('enum', 'const') LOOP + SELECT t.schema INTO sub_schema + FROM @extschema@.json_schema_resolve_refs( + sub_schema, + base_uri, + base_path, + resolved_ids_mapping, + NOT resolve_refs OR (resolve_refs AND key NOT IN ('properties')) + ) t; + schema := jsonb_set(schema, ARRAY [key], sub_schema); + END LOOP; + + ELSEIF jsonb_typeof(schema) = 'array' THEN + FOR idx IN 0..jsonb_array_length(schema) - 1 LOOP + SELECT t.schema INTO sub_schema + FROM @extschema@.json_schema_resolve_refs(schema->idx, base_uri, base_path, resolved_ids_mapping, resolve_refs) t; + schema := jsonb_set(schema, ARRAY [idx::text], sub_schema); + END LOOP; + END IF; + END; +$f$ LANGUAGE plpgsql IMMUTABLE; + + +CREATE OR REPLACE FUNCTION json_schema_resolve_ref( + ref text, + base_uri text, + base_path text, + resolved_ids_mapping jsonb +) RETURNS text[] + AS $f$ + DECLARE + v_parts text[]; + v_frag text := ''; + v_uri text := ''; + v_path jsonb; + BEGIN + -- a ref could be to a $id or a json property path. + v_parts := string_to_array(ref, '#'); + IF array_length(v_parts, 1) < 2 THEN + -- we only have one part + v_uri = v_parts[1]; + ELSE + v_uri = v_parts[1]; + v_frag = v_parts[2]; + END IF; + + IF v_frag != '' THEN + v_parts := ARRAY( + SELECT @extschema@.urldecode_arr(replace(replace(path_part, '~1', '/'), '~0', '~')) + FROM UNNEST(string_to_array(v_frag, '/')) path_part + ); + IF v_uri LIKE 'urn:%' AND v_frag LIKE '/%' THEN + -- urn:something:there#/frag/part + -- /frag/json/pointer/part + v_parts := v_parts[2:]; + ELSEIF v_uri != '' AND array_length(v_parts, 1) > 0 THEN + -- http://example.com/path#foo.json + v_uri := v_uri || '#' || v_parts[1]; + -- /frag/json/pointer/part + v_parts := v_parts[2:]; + ELSEIF v_parts[1] = '' THEN + -- #/frag/json/pointer/part without the first item which is empty + v_parts := v_parts[2:]; + END IF; + ELSE + v_parts := '{}'::text[]; + END IF; + + IF v_uri != '' THEN + v_uri := (@extschema@.json_schema_resolve_uri(v_uri, base_uri, base_path)).resolved_uri; + IF resolved_ids_mapping IS NULL THEN + RETURN NULL; + END IF; + IF NOT resolved_ids_mapping ? v_uri THEN + RETURN NULL; + END IF; + RETURN ARRAY(SELECT jsonb_array_elements_text(resolved_ids_mapping->v_uri)) || v_parts; + ELSEIF v_frag = '' THEN + RETURN ARRAY[]::text[]; + ELSEIF resolved_ids_mapping ? (base_uri || base_path) THEN + v_path := resolved_ids_mapping->(base_uri || base_path); + RETURN ARRAY(SELECT jsonb_array_elements_text(v_path)) || v_parts; + ELSEIF (ref ~ '^#.[^/]+$') AND resolved_ids_mapping ? ref THEN + RETURN ARRAY(SELECT jsonb_array_elements_text(resolved_ids_mapping->ref)); + ELSE + RETURN v_parts; + END IF; + END; +$f$ LANGUAGE plpgsql IMMUTABLE; + +CREATE OR REPLACE FUNCTION json_schema_resolve_ids_to_paths ( + schema jsonb, + path text[], + base_uri text, + base_path text +) RETURNS TABLE ( + resolved_uri text, + resolved_path text[] + ) AS $f$ + DECLARE + id text; + V_resolved_uri ALIAS FOR resolved_uri; + BEGIN + IF schema ? 'id' THEN + id := schema->>'id'; + ELSEIF schema ? '$id' THEN + id := schema->>'$id'; + END IF; + IF id IS NOT NULL THEN + SELECT t.resolved_uri, t.base_uri, t.base_path + INTO V_resolved_uri, base_uri, base_path + FROM @extschema@.json_schema_resolve_uri(id, base_uri, base_path) t; + END IF; + + IF jsonb_typeof(schema) = 'object' THEN + RETURN QUERY SELECT q.* + FROM jsonb_object_keys(schema) t(key), + @extschema@.json_schema_resolve_ids_to_paths(schema->(t.key), path || t.key, base_uri, base_path) q; + + + ELSEIF jsonb_typeof(schema) = 'array' THEN + RETURN QUERY SELECT q.* + FROM jsonb_array_elements(schema) WITH ORDINALITY t(elem, idx), + @extschema@.json_schema_resolve_ids_to_paths(elem, path || (idx - 1)::text, base_uri, base_path) q; + + END IF; + resolved_path := path; + RETURN NEXT; + END; +$f$ LANGUAGE plpgsql IMMUTABLE; + +CREATE OR REPLACE FUNCTION json_schema_resolve_ids_to_paths(schema jsonb) RETURNS TABLE ( + resolved_uri text, + resolved_path text[] + ) AS $$ + SELECT * FROM @extschema@.json_schema_resolve_ids_to_paths(schema, '{}'::text[], null, null) t + WHERE t.resolved_uri IS NOT NULL; +$$ LANGUAGE SQL IMMUTABLE ; + +CREATE OR REPLACE FUNCTION json_schema_resolve_refs(schema jsonb) RETURNS jsonb AS $$ + SELECT schema FROM @extschema@.json_schema_resolve_refs( + schema, + null, + null, + (SELECT jsonb_object_agg(resolved_uri, resolved_path) FROM @extschema@.json_schema_resolve_ids_to_paths(schema)), + true + ); +$$ LANGUAGE SQL IMMUTABLE ; diff --git a/postgres-json-schema.control b/postgres-json-schema.control index eaaf496..d35f4af 100644 --- a/postgres-json-schema.control +++ b/postgres-json-schema.control @@ -1,3 +1,3 @@ comment = 'Validate JSON schemas' relocatable = false -default_version = '0.1.1' +default_version = '0.2.0' diff --git a/test.py b/test.py index d464555..1295df6 100644 --- a/test.py +++ b/test.py @@ -13,35 +13,60 @@ EXCLUDE_FILES = {'optional', 'refRemote.json', 'definitions.json'} EXCLUDE_TESTS = { # json-schema-org/JSON-Schema-Test-Suite#130 - ('ref.json', 'escaped pointer ref', 'percent invalid'), +# ('ref.json', 'escaped pointer ref', 'percent invalid'), # json-schema-org/JSON-Schema-Test-Suite#114 - ('ref.json', 'remote ref, containing refs itself', 'remote ref invalid'), + ('ref.json', 'remote ref, containing refs itself'), +# ('id.json', 'id inside an enum is not a real identifier'), + + # nul bytes are not supported by postgres + ('enum.json', 'nul characters in strings'), + ('const.json', 'nul characters in strings'), + + # we are implementing like draft 2019 so we do include sibling props + ('ref.json', 'ref overrides any sibling keywords'), } -os.chdir('JSON-Schema-Test-Suite/tests/draft4') +if '--dir' in sys.argv: + idx = sys.argv.index('--dir') + dir_name = sys.argv[idx+1] + test_files = sys.argv[1:idx] + sys.argv[idx+2:] +else: + dir_name = 'JSON-Schema-Test-Suite/tests/draft4' + test_files = sys.argv[1:] + +print(f'switching to {dir_name} {sys.argv}') +#os.chdir(dir_name) failures = 0 -test_files = sys.argv[1:] if not test_files: - test_files = [test_file for test_file in os.listdir('.') if test_file not in EXCLUDE_FILES] + test_files = [os.path.join(dir_name, test_file) for test_file in os.listdir(dir_name) if test_file not in EXCLUDE_FILES] for test_file in test_files: with open(test_file) as f: + test_file = os.path.basename(test_file) suites = json.load(f) for suite in suites: for test in suite['tests']: + if (test_file, suite['description']) in EXCLUDE_TESTS: + continue if (test_file, suite['description'], test['description']) in EXCLUDE_TESTS: continue + command_args = ['SELECT validate_json_schema(json_schema_resolve_refs(%s), %s)', (json.dumps(suite['schema']), json.dumps(test['data']))] + def fail(e): - print("%s: validate_json_schema('%s', '%s')" % (test_file, json.dumps(suite['schema']), json.dumps(test['data']))) + cmd = command_args[0] % tuple("'%s'" % x for x in command_args[1]) + print("%s: %s" % (test_file, cmd)) print('Failed: %s: %s. %s' % (suite['description'], test['description'], e)) try: - cur.execute('SELECT validate_json_schema(%s, %s)', (json.dumps(suite['schema']), json.dumps(test['data']))) + cur.execute(command_args[0], command_args[1]) except psycopg2.DataError as e: fail(e) failures += 1 + except psycopg2.errors.StatementTooComplex as e: + fail(e) + exit(1) else: valid, = cur.fetchone() if valid != test['valid']: diff --git a/tests.sql b/tests.sql index 9911699..1b53658 100644 --- a/tests.sql +++ b/tests.sql @@ -1,4 +1,8 @@ -CREATE OR REPLACE FUNCTION run_tests() RETURNS boolean AS $f$ +CREATE SCHEMA IF NOT EXISTS j; + CREATE EXTENSION IF NOT EXISTS "postgres-json-schema" SCHEMA j; + SET SEARCH_PATH TO j, public; + +DO $f$ BEGIN ASSERT validate_json_schema('{}', '{}'); ASSERT NOT validate_json_schema('{"type": "object"}', '1'); @@ -56,9 +60,263 @@ BEGIN ASSERT validate_json_schema('{"enum": [1,2,3]}', '1'); ASSERT NOT validate_json_schema('{"enum": [1,2,3]}', '4'); - - RETURN true; END; $f$ LANGUAGE 'plpgsql'; -SELECT run_tests(); + +DO $f$ +BEGIN + ASSERT (SELECT (resolved_uri, base_uri, base_path) IS NOT DISTINCT FROM ('http://example.com:1234/hello/world.json#foo', 'http://example.com:1234', '/hello/world.json#foo') FROM json_schema_resolve_uri('#foo', 'http://example.com:1234', '/hello/world.json')); + ASSERT (SELECT (resolved_uri, base_uri, base_path) IS NOT DISTINCT FROM ('http://example.com:1234/foo/prefix/hello/world', 'http://example.com:1234', '/foo/prefix/hello/world') FROM json_schema_resolve_uri('hello/world', 'http://example.com:1234', '/foo/prefix/')); + ASSERT (SELECT (resolved_uri, base_uri, base_path) IS NOT DISTINCT FROM ('http://example.com:1234/foo/hello/world', 'http://example.com:1234', '/foo/hello/world') FROM json_schema_resolve_uri('hello/world', 'http://example.com:1234', '/foo/prefix')); + ASSERT (SELECT (resolved_uri, base_uri, base_path) IS NOT DISTINCT FROM ('http://example.com:1234/hello/world', 'http://example.com:1234', '/hello/world') FROM json_schema_resolve_uri('http://crazy.com:1234/hello/world', 'http://example.com:1234', '/foo/prefix/')); + ASSERT (SELECT (resolved_uri, base_uri, base_path) IS NOT DISTINCT FROM ('http://example.com:1234/hello/world', 'http://example.com:1234', '/hello/world') FROM json_schema_resolve_uri('http://example.com:1234/hello/world')); + ASSERT (SELECT (resolved_uri, base_uri, base_path) IS NOT DISTINCT FROM ('http://example.com:1234/hello/world', 'http://example.com:1234', '/hello/world') FROM json_schema_resolve_uri('/hello/world', 'http://example.com:1234', '/foo/prefix')); + ASSERT (SELECT (resolved_uri, base_uri, base_path) IS NOT DISTINCT FROM ('http://localhost:1234/nested.json#foo', 'http://localhost:1234', '/nested.json#foo') FROM json_schema_resolve_uri('http://localhost:1234/nested.json#foo', null, null)); + ASSERT (SELECT (resolved_uri, base_uri, base_path) IS NOT DISTINCT FROM ('http://localhost:1234/nested.json#foo', 'http://localhost:1234', '/nested.json#foo') FROM json_schema_resolve_uri('http://localhost:1234/nested.json#foo')); + ASSERT (SELECT (resolved_uri, base_uri, base_path) IS NOT DISTINCT FROM ('/hello/world', null, '/hello/world') FROM json_schema_resolve_uri('/hello/world')); + ASSERT (SELECT (resolved_uri, base_uri, base_path) IS NOT DISTINCT FROM ('#foo', null, '#foo') FROM json_schema_resolve_uri('#foo')); + ASSERT (SELECT (resolved_uri, base_uri, base_path) IS NOT DISTINCT FROM ('#foo', null, '#foo') FROM json_schema_resolve_uri('#foo')); + ASSERT (SELECT (resolved_uri, base_uri, base_path) IS NOT DISTINCT FROM ('http://localhost:1234/sibling_id/base/foo.json', 'http://localhost:1234', '/sibling_id/base/foo.json') FROM json_schema_resolve_uri('foo.json', 'http://localhost:1234', '/sibling_id/base/')); + ASSERT (SELECT (resolved_uri, base_uri, base_path) IS NOT DISTINCT FROM ('http://localhost:1234/sibling_id/foo.json', 'http://localhost:1234', '/sibling_id/foo.json') FROM json_schema_resolve_uri('foo.json', 'http://localhost:1234', '/sibling_id/base')); + ASSERT (SELECT (resolved_uri, base_uri, base_path) IS NOT DISTINCT FROM ('urn:uuid:deadbeef-1234-0000-0000-4321feebdaed#/$defs/bar', 'urn:uuid:deadbeef-1234-0000-0000-4321feebdaed', '') FROM json_schema_resolve_uri('urn:uuid:deadbeef-1234-0000-0000-4321feebdaed#/$defs/bar')); +END; +$f$; + + +DO $f$ +BEGIN + ASSERT (SELECT (resolved_uri, resolved_path) = ('#foo', '{definitions,A}'::text[]) FROM json_schema_resolve_ids_to_paths('{"allOf": [{"$ref": "#foo"}], "definitions": {"A": {"id": "#foo", "type": "integer"}}}')); + ASSERT (SELECT jsonb_object_agg(resolved_uri, resolved_path) = '{"http://example.com/schema-relative-uri-defs1.json": [], "http://example.com/schema-relative-uri-defs2.json": ["properties", "foo"]}' FROM json_schema_resolve_ids_to_paths('{"$id": "http://example.com/schema-relative-uri-defs1.json", "properties": {"foo": {"$id": "schema-relative-uri-defs2.json", "definitions": {"inner": {"properties": {"bar": {"type": "string"}}}}, "allOf": [{"$ref": "#/definitions/inner"}]}}, "allOf": [{"$ref": "schema-relative-uri-defs2.json"}]}')); + ASSERT (SELECT jsonb_object_agg(resolved_uri, resolved_path) = '{"http://localhost:1234/sibling_id/": ["allOf", "0"], "http://localhost:1234/sibling_id/base/": [], "http://localhost:1234/sibling_id/foo.json": ["definitions", "foo"], "http://localhost:1234/sibling_id/base/foo.json": ["definitions", "base_foo"]}' FROM json_schema_resolve_ids_to_paths('{"id": "http://localhost:1234/sibling_id/base/", "definitions": {"foo": {"id": "http://localhost:1234/sibling_id/foo.json", "type": "string"}, "base_foo": {"$comment": "this canonical uri is http://localhost:1234/sibling_id/base/foo.json", "id": "foo.json", "type": "number"}}, "allOf": [{"$comment": "$ref resolves to http://localhost:1234/sibling_id/base/foo.json, not http://localhost:1234/sibling_id/foo.json", "id": "http://localhost:1234/sibling_id/", "$ref": "foo.json"}]}')); + ASSERT (SELECT jsonb_object_agg(resolved_uri, resolved_path) = '{"http://localhost:1234/root": [], "http://localhost:1234/nested.json": ["definitions", "A"], "http://localhost:1234/nested.json#foo": ["definitions", "A", "definitions", "B"]}' FROM json_schema_resolve_ids_to_paths('{"$id": "http://localhost:1234/root", "allOf": [{"$ref": "http://localhost:1234/nested.json#foo"}], "definitions": {"A": {"$id": "nested.json", "definitions": {"B": {"$id": "#foo", "type": "integer"}}}}}')); + ASSERT (SELECT jsonb_object_agg(resolved_uri, resolved_path) = '{"urn:uuid:deadbeef-1234-0000-0000-4321feebdaed": []}' FROM json_schema_resolve_ids_to_paths('{"$id": "urn:uuid:deadbeef-1234-0000-0000-4321feebdaed", "properties": {"foo": {"$ref": "urn:uuid:deadbeef-1234-0000-0000-4321feebdaed#/$defs/bar"}}, "$defs": {"bar": {"type": "string"}}}')); +END; +$f$; + + +DO $f$ +BEGIN + ASSERT (SELECT a->'properties'->'foo'->'allOf'->0->'$_resolvedRef' = '["properties", "foo", "definitions", "inner"]' FROM json_schema_resolve_refs('{"$id": "http://example.com/schema-relative-uri-defs1.json", "properties": {"foo": {"$id": "schema-relative-uri-defs2.json", "definitions": {"inner": {"properties": {"bar": {"type": "string"}}}}, "allOf": [{"$ref": "#/definitions/inner"}]}}, "allOf": [{"$ref": "schema-relative-uri-defs2.json"}]}') a); + ASSERT (SELECT a->'properties'->'properties'->'allOf'->0->'$_resolvedRef' = '["properties", "properties", "definitions", "inner"]' FROM json_schema_resolve_refs('{"$id": "http://example.com/schema-relative-uri-defs1.json", "properties": {"properties": {"$id": "schema-relative-uri-defs2.json", "definitions": {"inner": {"properties": {"bar": {"type": "string"}}}}, "allOf": [{"$ref": "#/definitions/inner"}]}}, "allOf": [{"$ref": "schema-relative-uri-defs2.json"}]}') a); + ASSERT (SELECT a->'allOf'->0->'$_resolvedRef' = '["definitions", "base_foo"]'::jsonb FROM json_schema_resolve_refs('{"id": "http://localhost:1234/sibling_id/base/", "definitions": {"foo": {"id": "http://localhost:1234/sibling_id/foo.json", "type": "string"}, "base_foo": {"$comment": "this canonical uri is http://localhost:1234/sibling_id/base/foo.json", "id": "foo.json", "type": "number"}}, "allOf": [{"$comment": "$ref resolves to http://localhost:1234/sibling_id/base/foo.json, not http://localhost:1234/sibling_id/foo.json", "id": "http://localhost:1234/sibling_id/", "$ref": "foo.json"}]}') a); + + ASSERT (SELECT '{"type": "array", "items": [{"$ref": "#/definitions/item", "$_resolvedRef": ["definitions", "item"]}, {"$ref": "#/definitions/item", "$_resolvedRef": ["definitions", "item"]}, {"$ref": "#/definitions/item", "$_resolvedRef": ["definitions", "item"]}], "definitions": {"item": {"type": "array", "items": [{"$ref": "#/definitions/sub-item", "$_resolvedRef": ["definitions", "sub-item"]}, {"$ref": "#/definitions/sub-item", "$_resolvedRef": ["definitions", "sub-item"]}], "additionalItems": false}, "sub-item": {"type": "object", "required": ["foo"]}}, "additionalItems": false}'::jsonb = json_schema_resolve_refs('{"definitions": {"item": {"type": "array", "additionalItems": false, "items": [{"$ref": "#/definitions/sub-item"}, {"$ref": "#/definitions/sub-item"}]}, "sub-item": {"type": "object", "required": ["foo"]}}, "type": "array", "additionalItems": false, "items": [{"$ref": "#/definitions/item"}, {"$ref": "#/definitions/item"}, {"$ref": "#/definitions/item"}]}')); + ASSERT (SELECT '{"$id": "http://localhost:1234/tree", "type": "object", "required": ["meta", "nodes"], "properties": {"meta": {"type": "string"}, "nodes": {"type": "array", "items": {"$ref": "node", "$_resolvedRef": ["definitions", "node"]}}}, "definitions": {"node": {"$id": "http://localhost:1234/node", "type": "object", "required": ["value"], "properties": {"value": {"type": "number"}, "subtree": {"$ref": "tree", "$_resolvedRef": []}}, "description": "node"}}, "description": "tree of nodes"}'::jsonb = json_schema_resolve_refs('{"$id": "http://localhost:1234/tree", "description": "tree of nodes", "type": "object", "properties": {"meta": {"type": "string"}, "nodes": {"type": "array", "items": {"$ref": "node"}}}, "required": ["meta", "nodes"], "definitions": {"node": {"$id": "http://localhost:1234/node", "description": "node", "type": "object", "properties": {"value": {"type": "number"}, "subtree": {"$ref": "tree"}}, "required": ["value"]}}}')); + + ASSERT (SELECT json_schema_resolve_refs('{"properties": {"$ref": {"type": "string"}}}') = '{"properties": {"$ref": {"type": "string"}}}'); + ASSERT (SELECT json_schema_resolve_refs('{"allOf": [{"$ref": "#foo"}], "definitions": {"A": {"id": "#foo", "type": "integer"}}}') = '{"allOf": [{"$ref": "#foo", "$_resolvedRef": ["definitions", "A"]}], "definitions": {"A": {"id": "#foo", "type": "integer"}}}'); + + ASSERT (SELECT json_schema_resolve_refs('{"allOf": [{"$ref": "#/definitions/bool"}], "definitions": {"bool": true}}') = '{"allOf": [{"$ref": "#/definitions/bool", "$_resolvedRef": ["definitions", "bool"]}], "definitions": {"bool": true}}'); + ASSERT (SELECT json_schema_resolve_refs('{"properties": {"$ref": {"$ref": "#/definitions/is-string"}}, "definitions": {"is-string": {"type": "string"}}}') = '{"properties": {"$ref": {"$ref": "#/definitions/is-string", "$_resolvedRef": ["definitions", "is-string"]}}, "definitions": {"is-string": {"type": "string"}}}'); + + ASSERT (SELECT json_schema_resolve_refs('{"$id": "urn:uuid:deadbeef-1234-0000-0000-4321feebdaed", "properties": {"foo": {"$ref": "urn:uuid:deadbeef-1234-0000-0000-4321feebdaed#/$defs/bar"}}, "$defs": {"bar": {"type": "string"}}}') = '{"$id": "urn:uuid:deadbeef-1234-0000-0000-4321feebdaed", "$defs": {"bar": {"type": "string"}}, "properties": {"foo": {"$ref": "urn:uuid:deadbeef-1234-0000-0000-4321feebdaed#/$defs/bar", "$_resolvedRef": ["$defs", "bar"]}}}'); + + ASSERT (SELECT json_schema_resolve_refs('{"properties": {"foo": {"$ref": "#"}}, "additionalProperties": false}') = '{"properties": {"foo": {"$ref": "#", "$_resolvedRef": []}}, "additionalProperties": false}'); + + ASSERT (SELECT json_schema_resolve_refs('{"properties": {"$ref": {"type": "string"}}}') = '{"properties": {"$ref": {"type": "string"}}}'); +END; +$f$; + + +DO $f$ +BEGIN + ASSERT (SELECT '{foo}'::text[] = json_schema_resolve_ref('#foo', null, null, null)); + ASSERT (SELECT '{definitions,item}'::text[] = json_schema_resolve_ref('#/definitions/item', null, null, null)); + ASSERT (SELECT '{}'::text[] = json_schema_resolve_ref('#', null, null, null)); + ASSERT (SELECT '{definitions,base_foo}'::text[] = json_schema_resolve_ref('foo.json', 'http://localhost:1234', '/sibling_id/base/', '{"http://localhost:1234/sibling_id/base/foo.json": ["definitions","base_foo"]}')); + ASSERT (SELECT '{$defs,bar}'::text[] = json_schema_resolve_ref('urn:uuid:deadbeef-1234-0000-0000-4321feebdaed#/$defs/bar', null, null, '{"urn:uuid:deadbeef-1234-0000-0000-4321feebdaed": []}')); + 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"]}')); +END; +$f$; + + +CREATE OR REPLACE FUNCTION test_raises_exception( + text, + expected jsonb, + OUT result bool, OUT msg text +) AS $f$ + DECLARE + RETURNED_SQLSTATE text; + COLUMN_NAME text; + CONSTRAINT_NAME text; + PG_DATATYPE_NAME text; + MESSAGE_TEXT text; + TABLE_NAME text; + SCHEMA_NAME text; + PG_EXCEPTION_DETAIL text; + PG_EXCEPTION_HINT text; + PG_EXCEPTION_CONTEXT text; + v_vars jsonb; + v_key text; + v_value text; + BEGIN + result := false; + msg := 'No exception raised'; + execute ( $1 ); + EXCEPTION + WHEN others THEN + GET STACKED DIAGNOSTICS + RETURNED_SQLSTATE := RETURNED_SQLSTATE, + COLUMN_NAME := COLUMN_NAME, + CONSTRAINT_NAME := CONSTRAINT_NAME, + PG_DATATYPE_NAME := PG_DATATYPE_NAME, + MESSAGE_TEXT := MESSAGE_TEXT, + TABLE_NAME := TABLE_NAME, + SCHEMA_NAME := SCHEMA_NAME, + PG_EXCEPTION_DETAIL := PG_EXCEPTION_DETAIL, + PG_EXCEPTION_HINT := PG_EXCEPTION_HINT, + PG_EXCEPTION_CONTEXT := PG_EXCEPTION_CONTEXT; + + v_vars := jsonb_build_object( + 'RETURNED_SQLSTATE', RETURNED_SQLSTATE, + 'COLUMN_NAME', COLUMN_NAME, + 'CONSTRAINT_NAME', CONSTRAINT_NAME, + 'PG_DATATYPE_NAME', PG_DATATYPE_NAME, + 'MESSAGE_TEXT', MESSAGE_TEXT, + 'TABLE_NAME', TABLE_NAME, + 'SCHEMA_NAME', SCHEMA_NAME, + 'PG_EXCEPTION_DETAIL', PG_EXCEPTION_DETAIL, + 'PG_EXCEPTION_HINT', PG_EXCEPTION_HINT, + 'PG_EXCEPTION_CONTEXT', PG_EXCEPTION_CONTEXT + ); + IF expected IS NOT NULL THEN + FOR v_key, v_value IN SELECT k, coalesce(expected->>k, expected->>lower(k)) FROM jsonb_object_keys(v_vars) k LOOP + + IF v_value IS NOT NULL AND v_vars->>v_key NOT ILIKE v_value THEN + result := false; + msg := format('%s: %s != Expected %s', v_key, v_vars->>v_key, v_value); + RETURN; + END IF; + END LOOP; + END IF; + + result := true; + msg := MESSAGE_TEXT; + END; + +$f$ LANGUAGE plpgsql VOLATILE ; + + + +DO $f$ +BEGIN + ASSERT (SELECT true = null::json_schema_validation_result::bool); + ASSERT (SELECT true = (null)::json_schema_validation_result::bool); + ASSERT (SELECT true = (null, null)::json_schema_validation_result::bool); + ASSERT (SELECT true = ('{path,to,field}', null)::json_schema_validation_result::bool); + + 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"}' ) ); + 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[]"}' ) ); + + ASSERT (SELECT NOT (NOT NULL::json_schema_validation_result)); + ASSERT (SELECT NOT (NOT NULL::json_schema_validation_result)); + ASSERT (SELECT NOT ('{path,to,field}', 'FAILED')::json_schema_validation_result); + ASSERT (SELECT NOT ARRAY[('{path,to,field}', 'FAILED')]::json_schema_validation_result[]); + ASSERT (SELECT NOT ARRAY[('{path,to,field}', 'FAILED')]::json_schema_validation_result[]); + ASSERT (SELECT NOT ARRAY[NULL, ('{path,to,field}', 'FAILED')]::json_schema_validation_result[]); + ASSERT (SELECT ARRAY[NULL]::json_schema_validation_result[]); + ASSERT (SELECT ARRAY[('{path,to,field}', null)]::json_schema_validation_result[]::bool); + ASSERT (SELECT NULL::json_schema_validation_result[]::bool); + +END; +$f$; + + +DO $f$ +DECLARE + v_result RECORD; + v_schema1 jsonb := $$ { + "definitions": { + "reffed": { + "type": "array" + } + }, + "properties": { + "foo": { + "$ref": "#/definitions/reffed", + "maxItems": 2 + } + } + } $$; + + v_schema2 jsonb := $${ + "definitions": { + "reffed": { + "type": "array" + } + }, + "properties": { + "foo": { + "type": "array", + "maxItems": 2, + "items": { + "type": "number" + } + } + } + } $$; +BEGIN + + 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; + ASSERT v_result.valid, v_result; + 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; + ASSERT v_result.valid, v_result; + SELECT INTO v_result *, ARRAY[]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations(v_schema1, $$ { "foo": ["string", 1] } $$) a; + ASSERT v_result.valid, v_result; + 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; + ASSERT v_result.valid, v_result; + 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; + ASSERT v_result.valid, v_result; + -- test string is not valid even if it is all digits when string_as_number is false + 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; + ASSERT v_result.valid, v_result; + -- test quoted number is valid when string_as_number is true with a literal string + SELECT INTO v_result *, ARRAY[]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations('{"type": "number"}', $$"1"$$, true) a; + ASSERT v_result.valid, v_result; + -- test quoted number is valid when string_as_number is true with a literal decimal string + SELECT INTO v_result *, ARRAY[]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations('{"type": "number"}', $$"1.1"$$, true) a; + ASSERT v_result.valid, v_result; + -- test quoted number is valid when string_as_number is true with an object + 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; + ASSERT v_result.valid, v_result; + -- test quoted number is valid when string_as_number is true with an array + SELECT INTO v_result *, ARRAY[]::json_schema_validation_result[] = a AS valid FROM get_json_schema_validations(v_schema2, $$ { "foo": ["0"] } $$, true) a; + ASSERT v_result.valid, v_result; + + -- test quoted number when string_as_number is true with a invalid numerical string + 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; + ASSERT v_result.valid, v_result; + + -- test quoted number when string_as_number is true with a invalid numerical string + 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; + ASSERT v_result.valid, v_result; + + -- test quoted integer is not valid even when string_as_number is true + 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; + ASSERT v_result.valid, v_result; + + 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"}]}'); + ASSERT v_result.result = true, v_result; + -- does not raise any exception for valid string + ASSERT true = json_schema_check_constraint('{"type": "number"}', '"1.9"', true); + + -- create the table + EXECUTE format($$ CREATE TEMPORARY TABLE test_entry (data jsonb CHECK ( validate_json_schema(%L, data) )) ON COMMIT DROP$$, v_schema1); + -- valid data + INSERT INTO test_entry VALUES ('{ "foo": ["string", 1] }'); + -- invalid data + 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\""}'); + ASSERT v_result.result = true, v_result; + + -- Create the table + EXECUTE format($$ CREATE TEMPORARY TABLE test_entry_with_detailed_message (data jsonb CHECK ( json_schema_check_constraint(%L, data) )) ON COMMIT DROP$$, v_schema1); + -- test valid data + INSERT INTO test_entry_with_detailed_message VALUES ('{ "foo": ["string", 1] }'); + -- test invalid data + + 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"}] }' ); + ASSERT v_result.result = true, v_result; + +END +$f$;