Skip to content

Commit 232634a

Browse files
authored
Add support for array operators (#127)
* add support for array operators * update changelog to reflect fix for #123 * add more array tests, make sure cql2_ops table is up-to-date in incremental migration
1 parent 42d512e commit 232634a

File tree

9 files changed

+3150
-3
lines changed

9 files changed

+3150
-3
lines changed

CHANGELOG.md

Lines changed: 5 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,9 @@
11
# Changelog
2+
## [v0.6.6]
3+
### Added
4+
- Add support for array operators in CQL2 (a_equals, a_contains, a_contained_by, a_overlaps).
5+
- Add check in loader to make sure that pypgstac and pgstac versions match before loading data [#123](https://github.com/stac-utils/pgstac/issues/123)
6+
27
## [v0.6.5]
38
### Fixed
49
- Fix for type casting when using the "in" operator [#122](https://github.com/stac-utils/pgstac/issues/122)
Lines changed: 216 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,216 @@
1+
SET SEARCH_PATH to pgstac, public;
2+
set check_function_bodies = off;
3+
4+
CREATE OR REPLACE FUNCTION pgstac.cql2_query(j jsonb, wrapper text DEFAULT NULL::text)
5+
RETURNS text
6+
LANGUAGE plpgsql
7+
STABLE
8+
AS $function$
9+
#variable_conflict use_variable
10+
DECLARE
11+
args jsonb := j->'args';
12+
arg jsonb;
13+
op text := lower(j->>'op');
14+
cql2op RECORD;
15+
literal text;
16+
_wrapper text;
17+
leftarg text;
18+
rightarg text;
19+
BEGIN
20+
IF j IS NULL OR (op IS NOT NULL AND args IS NULL) THEN
21+
RETURN NULL;
22+
END IF;
23+
RAISE NOTICE 'CQL2_QUERY: %', j;
24+
IF j ? 'filter' THEN
25+
RETURN cql2_query(j->'filter');
26+
END IF;
27+
28+
IF j ? 'upper' THEN
29+
RETURN cql2_query(jsonb_build_object('op', 'upper', 'args', j->'upper'));
30+
END IF;
31+
32+
IF j ? 'lower' THEN
33+
RETURN cql2_query(jsonb_build_object('op', 'lower', 'args', j->'lower'));
34+
END IF;
35+
36+
-- Temporal Query
37+
IF op ilike 't_%' or op = 'anyinteracts' THEN
38+
RETURN temporal_op_query(op, args);
39+
END IF;
40+
41+
-- If property is a timestamp convert it to text to use with
42+
-- general operators
43+
IF j ? 'timestamp' THEN
44+
RETURN format('%L::timestamptz', to_tstz(j->'timestamp'));
45+
END IF;
46+
IF j ? 'interval' THEN
47+
RAISE EXCEPTION 'Please use temporal operators when using intervals.';
48+
RETURN NONE;
49+
END IF;
50+
51+
-- Spatial Query
52+
IF op ilike 's_%' or op = 'intersects' THEN
53+
RETURN spatial_op_query(op, args);
54+
END IF;
55+
56+
IF op IN ('a_equals','a_contains','a_contained_by','a_overlaps') THEN
57+
IF args->0 ? 'property' THEN
58+
leftarg := format('to_text_array(%s)', (queryable(args->0->>'property')).path);
59+
END IF;
60+
IF args->1 ? 'property' THEN
61+
rightarg := format('to_text_array(%s)', (queryable(args->1->>'property')).path);
62+
END IF;
63+
RETURN FORMAT(
64+
'%s %s %s',
65+
COALESCE(leftarg, quote_literal(to_text_array(args->0))),
66+
CASE op
67+
WHEN 'a_equals' THEN '='
68+
WHEN 'a_contains' THEN '@>'
69+
WHEN 'a_contained_by' THEN '<@'
70+
WHEN 'a_overlaps' THEN '&&'
71+
END,
72+
COALESCE(rightarg, quote_literal(to_text_array(args->1)))
73+
);
74+
END IF;
75+
76+
IF op = 'in' THEN
77+
RAISE NOTICE 'IN : % % %', args, jsonb_build_array(args->0), args->1;
78+
args := jsonb_build_array(args->0) || (args->1);
79+
RAISE NOTICE 'IN2 : %', args;
80+
END IF;
81+
82+
83+
84+
IF op = 'between' THEN
85+
args = jsonb_build_array(
86+
args->0,
87+
args->1->0,
88+
args->1->1
89+
);
90+
END IF;
91+
92+
-- Make sure that args is an array and run cql2_query on
93+
-- each element of the array
94+
RAISE NOTICE 'ARGS PRE: %', args;
95+
IF j ? 'args' THEN
96+
IF jsonb_typeof(args) != 'array' THEN
97+
args := jsonb_build_array(args);
98+
END IF;
99+
100+
IF jsonb_path_exists(args, '$[*] ? (@.property == "id" || @.property == "datetime" || @.property == "end_datetime" || @.property == "collection")') THEN
101+
wrapper := NULL;
102+
ELSE
103+
-- if any of the arguments are a property, try to get the property_wrapper
104+
FOR arg IN SELECT jsonb_path_query(args, '$[*] ? (@.property != null)') LOOP
105+
RAISE NOTICE 'Arg: %', arg;
106+
SELECT property_wrapper INTO wrapper
107+
FROM queryables
108+
WHERE name=(arg->>'property')
109+
LIMIT 1;
110+
RAISE NOTICE 'Property: %, Wrapper: %', arg, wrapper;
111+
IF wrapper IS NOT NULL THEN
112+
EXIT;
113+
END IF;
114+
END LOOP;
115+
116+
-- if the property was not in queryables, see if any args were numbers
117+
IF
118+
wrapper IS NULL
119+
AND jsonb_path_exists(args, '$[*] ? (@.type()=="number")')
120+
THEN
121+
wrapper := 'to_float';
122+
END IF;
123+
wrapper := coalesce(wrapper, 'to_text');
124+
END IF;
125+
126+
SELECT jsonb_agg(cql2_query(a, wrapper))
127+
INTO args
128+
FROM jsonb_array_elements(args) a;
129+
END IF;
130+
RAISE NOTICE 'ARGS: %', args;
131+
132+
IF op IN ('and', 'or') THEN
133+
RETURN
134+
format(
135+
'(%s)',
136+
array_to_string(to_text_array(args), format(' %s ', upper(op)))
137+
);
138+
END IF;
139+
140+
IF op = 'in' THEN
141+
RAISE NOTICE 'IN -- % %', args->0, to_text(args->0);
142+
RETURN format(
143+
'%s IN (%s)',
144+
to_text(args->0),
145+
array_to_string((to_text_array(args))[2:], ',')
146+
);
147+
END IF;
148+
149+
-- Look up template from cql2_ops
150+
IF j ? 'op' THEN
151+
SELECT * INTO cql2op FROM cql2_ops WHERE cql2_ops.op ilike op;
152+
IF FOUND THEN
153+
-- If specific index set in queryables for a property cast other arguments to that type
154+
155+
RETURN format(
156+
cql2op.template,
157+
VARIADIC (to_text_array(args))
158+
);
159+
ELSE
160+
RAISE EXCEPTION 'Operator % Not Supported.', op;
161+
END IF;
162+
END IF;
163+
164+
165+
IF wrapper IS NOT NULL THEN
166+
RAISE NOTICE 'Wrapping % with %', j, wrapper;
167+
IF j ? 'property' THEN
168+
RETURN format('%I(%s)', wrapper, (queryable(j->>'property')).path);
169+
ELSE
170+
RETURN format('%I(%L)', wrapper, j);
171+
END IF;
172+
ELSIF j ? 'property' THEN
173+
RETURN quote_ident(j->>'property');
174+
END IF;
175+
176+
RETURN quote_literal(to_text(j));
177+
END;
178+
$function$
179+
;
180+
181+
TRUNCATE cql2_ops;
182+
INSERT INTO cql2_ops (op, template, types) VALUES
183+
('eq', '%s = %s', NULL),
184+
('neq', '%s != %s', NULL),
185+
('ne', '%s != %s', NULL),
186+
('!=', '%s != %s', NULL),
187+
('<>', '%s != %s', NULL),
188+
('lt', '%s < %s', NULL),
189+
('lte', '%s <= %s', NULL),
190+
('gt', '%s > %s', NULL),
191+
('gte', '%s >= %s', NULL),
192+
('le', '%s <= %s', NULL),
193+
('ge', '%s >= %s', NULL),
194+
('=', '%s = %s', NULL),
195+
('<', '%s < %s', NULL),
196+
('<=', '%s <= %s', NULL),
197+
('>', '%s > %s', NULL),
198+
('>=', '%s >= %s', NULL),
199+
('like', '%s LIKE %s', NULL),
200+
('ilike', '%s ILIKE %s', NULL),
201+
('+', '%s + %s', NULL),
202+
('-', '%s - %s', NULL),
203+
('*', '%s * %s', NULL),
204+
('/', '%s / %s', NULL),
205+
('not', 'NOT (%s)', NULL),
206+
('between', '%s BETWEEN %s AND %s', NULL),
207+
('isnull', '%s IS NULL', NULL),
208+
('upper', 'upper(%s)', NULL),
209+
('lower', 'lower(%s)', NULL)
210+
ON CONFLICT (op) DO UPDATE
211+
SET
212+
template = EXCLUDED.template
213+
;
214+
215+
216+
SELECT set_version('0.6.6');

0 commit comments

Comments
 (0)