-
Notifications
You must be signed in to change notification settings - Fork 36
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
add fixes for casting items in filters to floats (#117)
* add fixes for casting items in filters to floats * fix for between case * update cql2_ops table * merge 116, update changelog Co-authored-by: Ubuntu <planetarycomputer@pct-bitner-vm.kko0dpzi4g3udak2ovyb5nsdte.ax.internal.cloudapp.net>
- Loading branch information
Showing
8 changed files
with
3,073 additions
and
38 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,185 @@ | ||
SET SEARCH_PATH to pgstac, public; | ||
set check_function_bodies = off; | ||
|
||
INSERT INTO cql2_ops (op, template, types) VALUES | ||
('eq', '%s = %s', NULL), | ||
('lt', '%s < %s', NULL), | ||
('lte', '%s <= %s', NULL), | ||
('gt', '%s > %s', NULL), | ||
('gte', '%s >= %s', NULL), | ||
('le', '%s <= %s', NULL), | ||
('ge', '%s >= %s', NULL), | ||
('=', '%s = %s', NULL), | ||
('<', '%s < %s', NULL), | ||
('<=', '%s <= %s', NULL), | ||
('>', '%s > %s', NULL), | ||
('>=', '%s >= %s', NULL), | ||
('like', '%s LIKE %s', NULL), | ||
('ilike', '%s ILIKE %s', NULL), | ||
('+', '%s + %s', NULL), | ||
('-', '%s - %s', NULL), | ||
('*', '%s * %s', NULL), | ||
('/', '%s / %s', NULL), | ||
('in', '%s = ANY (%s)', NULL), | ||
('not', 'NOT (%s)', NULL), | ||
('between', '%s BETWEEN %s AND %s', NULL), | ||
('isnull', '%s IS NULL', NULL), | ||
('upper', 'upper(%s)', NULL), | ||
('lower', 'lower(%s)', NULL) | ||
ON CONFLICT (op) DO UPDATE | ||
SET | ||
template = EXCLUDED.template | ||
; | ||
|
||
|
||
CREATE OR REPLACE FUNCTION pgstac.cql2_query(j jsonb, wrapper text DEFAULT NULL::text) | ||
RETURNS text | ||
LANGUAGE plpgsql | ||
STABLE | ||
AS $function$ | ||
#variable_conflict use_variable | ||
DECLARE | ||
args jsonb := j->'args'; | ||
arg jsonb; | ||
op text := lower(j->>'op'); | ||
cql2op RECORD; | ||
literal text; | ||
_wrapper text; | ||
BEGIN | ||
IF j IS NULL OR (op IS NOT NULL AND args IS NULL) THEN | ||
RETURN NULL; | ||
END IF; | ||
RAISE NOTICE 'CQL2_QUERY: %', j; | ||
IF j ? 'filter' THEN | ||
RETURN cql2_query(j->'filter'); | ||
END IF; | ||
|
||
IF j ? 'upper' THEN | ||
RETURN cql2_query(jsonb_build_object('op', 'upper', 'args', j->'upper')); | ||
END IF; | ||
|
||
IF j ? 'lower' THEN | ||
RETURN cql2_query(jsonb_build_object('op', 'lower', 'args', j->'lower')); | ||
END IF; | ||
|
||
-- Temporal Query | ||
IF op ilike 't_%' or op = 'anyinteracts' THEN | ||
RETURN temporal_op_query(op, args); | ||
END IF; | ||
|
||
-- If property is a timestamp convert it to text to use with | ||
-- general operators | ||
IF j ? 'timestamp' THEN | ||
RETURN format('%L::timestamptz', to_tstz(j->'timestamp')); | ||
END IF; | ||
IF j ? 'interval' THEN | ||
RAISE EXCEPTION 'Please use temporal operators when using intervals.'; | ||
RETURN NONE; | ||
END IF; | ||
|
||
-- Spatial Query | ||
IF op ilike 's_%' or op = 'intersects' THEN | ||
RETURN spatial_op_query(op, args); | ||
END IF; | ||
|
||
|
||
IF op = 'in' THEN | ||
RETURN format( | ||
'%s = ANY (%L)', | ||
cql2_query(args->0), | ||
to_text_array(args->1) | ||
); | ||
END IF; | ||
|
||
|
||
|
||
IF op = 'between' THEN | ||
args = jsonb_build_array( | ||
args->0, | ||
args->1->0, | ||
args->1->1 | ||
); | ||
END IF; | ||
|
||
-- Make sure that args is an array and run cql2_query on | ||
-- each element of the array | ||
RAISE NOTICE 'ARGS PRE: %', args; | ||
IF j ? 'args' THEN | ||
IF jsonb_typeof(args) != 'array' THEN | ||
args := jsonb_build_array(args); | ||
END IF; | ||
|
||
IF jsonb_path_exists(args, '$[*] ? (@.property == "id" || @.property == "datetime" || @.property == "end_datetime" || @.property == "collection")') THEN | ||
wrapper := NULL; | ||
ELSE | ||
-- if any of the arguments are a property, try to get the property_wrapper | ||
FOR arg IN SELECT jsonb_path_query(args, '$[*] ? (@.property != null)') LOOP | ||
RAISE NOTICE 'Arg: %', arg; | ||
SELECT property_wrapper INTO wrapper | ||
FROM queryables | ||
WHERE name=(arg->>'property') | ||
LIMIT 1; | ||
RAISE NOTICE 'Property: %, Wrapper: %', arg, wrapper; | ||
IF wrapper IS NOT NULL THEN | ||
EXIT; | ||
END IF; | ||
END LOOP; | ||
|
||
-- if the property was not in queryables, see if any args were numbers | ||
IF | ||
wrapper IS NULL | ||
AND jsonb_path_exists(args, '$[*] ? (@.type()=="number")') | ||
THEN | ||
wrapper := 'to_float'; | ||
END IF; | ||
wrapper := coalesce(wrapper, 'to_text'); | ||
END IF; | ||
|
||
SELECT jsonb_agg(cql2_query(a, wrapper)) | ||
INTO args | ||
FROM jsonb_array_elements(args) a; | ||
END IF; | ||
RAISE NOTICE 'ARGS: %', args; | ||
|
||
IF op IN ('and', 'or') THEN | ||
RETURN | ||
format( | ||
'(%s)', | ||
array_to_string(to_text_array(args), format(' %s ', upper(op))) | ||
); | ||
END IF; | ||
|
||
-- Look up template from cql2_ops | ||
IF j ? 'op' THEN | ||
SELECT * INTO cql2op FROM cql2_ops WHERE cql2_ops.op ilike op; | ||
IF FOUND THEN | ||
-- If specific index set in queryables for a property cast other arguments to that type | ||
RETURN format( | ||
cql2op.template, | ||
VARIADIC (to_text_array(args)) | ||
); | ||
ELSE | ||
RAISE EXCEPTION 'Operator % Not Supported.', op; | ||
END IF; | ||
END IF; | ||
|
||
|
||
IF wrapper IS NOT NULL THEN | ||
RAISE NOTICE 'Wrapping % with %', j, wrapper; | ||
IF j ? 'property' THEN | ||
RETURN format('%I(%s)', wrapper, (queryable(j->>'property')).path); | ||
ELSE | ||
RETURN format('%I(%L)', wrapper, j); | ||
END IF; | ||
ELSIF j ? 'property' THEN | ||
RETURN quote_ident(j->>'property'); | ||
END IF; | ||
|
||
RETURN quote_literal(to_text(j)); | ||
END; | ||
$function$ | ||
; | ||
|
||
|
||
|
||
SELECT set_version('0.6.4'); |
Oops, something went wrong.