Skip to content

Commit 1c0694e

Browse files
authoredAug 23, 2021
Make sure pgtap errors get caught (#46)
* Make sure features is at least [] * echo the entire pgtap log * Fixes for bugs with incorrectly referred parameters sort vs sortby, collection vs collections, and id vs ids * Add tests for fixes * bump version to 0.3.3
1 parent 77d8a71 commit 1c0694e

File tree

9 files changed

+2102
-117
lines changed

9 files changed

+2102
-117
lines changed
 

‎pypgstac/pypgstac/__init__.py

+1-1
Original file line numberDiff line numberDiff line change
@@ -1,2 +1,2 @@
11
"""PyPGStac Version."""
2-
__version__ = "0.3.2"
2+
__version__ = "0.3.3"
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,361 @@
1+
SET SEARCH_PATH to pgstac, public;
2+
set check_function_bodies = off;
3+
4+
CREATE OR REPLACE FUNCTION pgstac.add_filters_to_cql(j jsonb)
5+
RETURNS jsonb
6+
LANGUAGE plpgsql
7+
AS $function$
8+
DECLARE
9+
newprop jsonb;
10+
newprops jsonb := '[]'::jsonb;
11+
BEGIN
12+
IF j ? 'ids' THEN
13+
newprop := jsonb_build_object(
14+
'in',
15+
jsonb_build_array(
16+
'{"property":"id"}'::jsonb,
17+
j->'ids'
18+
)
19+
);
20+
newprops := jsonb_insert(newprops, '{1}', newprop);
21+
END IF;
22+
IF j ? 'collections' THEN
23+
newprop := jsonb_build_object(
24+
'in',
25+
jsonb_build_array(
26+
'{"property":"collection"}'::jsonb,
27+
j->'collections'
28+
)
29+
);
30+
newprops := jsonb_insert(newprops, '{1}', newprop);
31+
END IF;
32+
33+
IF j ? 'datetime' THEN
34+
newprop := format(
35+
'{"anyinteracts":[{"property":"datetime"}, %s]}',
36+
j->'datetime'
37+
);
38+
newprops := jsonb_insert(newprops, '{1}', newprop);
39+
END IF;
40+
41+
IF j ? 'bbox' THEN
42+
newprop := format(
43+
'{"intersects":[{"property":"geometry"}, %s]}',
44+
j->'bbox'
45+
);
46+
newprops := jsonb_insert(newprops, '{1}', newprop);
47+
END IF;
48+
49+
IF j ? 'intersects' THEN
50+
newprop := format(
51+
'{"intersects":[{"property":"geometry"}, %s]}',
52+
j->'intersects'
53+
);
54+
newprops := jsonb_insert(newprops, '{1}', newprop);
55+
END IF;
56+
57+
RAISE NOTICE 'newprops: %', newprops;
58+
59+
IF newprops IS NOT NULL AND jsonb_array_length(newprops) > 0 THEN
60+
return jsonb_set(
61+
j,
62+
'{filter}',
63+
cql_and_append(j, jsonb_build_object('and', newprops))
64+
) - '{ids,collections,datetime,bbox,intersects}'::text[];
65+
END IF;
66+
67+
return j;
68+
END;
69+
$function$
70+
;
71+
72+
CREATE OR REPLACE FUNCTION pgstac.get_token_filter(_search jsonb DEFAULT '{}'::jsonb, token_rec jsonb DEFAULT NULL::jsonb)
73+
RETURNS text
74+
LANGUAGE plpgsql
75+
AS $function$
76+
DECLARE
77+
token_id text;
78+
filters text[] := '{}'::text[];
79+
prev boolean := TRUE;
80+
field text;
81+
dir text;
82+
sort record;
83+
orfilters text[] := '{}'::text[];
84+
andfilters text[] := '{}'::text[];
85+
output text;
86+
token_where text;
87+
BEGIN
88+
-- If no token provided return NULL
89+
IF token_rec IS NULL THEN
90+
IF NOT (_search ? 'token' AND
91+
(
92+
(_search->>'token' ILIKE 'prev:%')
93+
OR
94+
(_search->>'token' ILIKE 'next:%')
95+
)
96+
) THEN
97+
RETURN NULL;
98+
END IF;
99+
prev := (_search->>'token' ILIKE 'prev:%');
100+
token_id := substr(_search->>'token', 6);
101+
SELECT to_jsonb(items) INTO token_rec FROM items WHERE id=token_id;
102+
END IF;
103+
RAISE NOTICE 'TOKEN ID: %', token_rec->'id';
104+
105+
CREATE TEMP TABLE sorts (
106+
_row int GENERATED ALWAYS AS IDENTITY NOT NULL,
107+
_field text PRIMARY KEY,
108+
_dir text NOT NULL,
109+
_val text
110+
) ON COMMIT DROP;
111+
112+
-- Make sure we only have distinct columns to sort with taking the first one we get
113+
INSERT INTO sorts (_field, _dir)
114+
SELECT
115+
(items_path(value->>'field')).path,
116+
get_sort_dir(value)
117+
FROM
118+
jsonb_array_elements(coalesce(_search->'sortby','[{"field":"datetime","direction":"desc"}]'))
119+
ON CONFLICT DO NOTHING
120+
;
121+
RAISE NOTICE 'sorts 1: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
122+
-- Get the first sort direction provided. As the id is a primary key, if there are any
123+
-- sorts after id they won't do anything, so make sure that id is the last sort item.
124+
SELECT _dir INTO dir FROM sorts ORDER BY _row ASC LIMIT 1;
125+
IF EXISTS (SELECT 1 FROM sorts WHERE _field = 'id') THEN
126+
DELETE FROM sorts WHERE _row > (SELECT _row FROM sorts WHERE _field = 'id' ORDER BY _row ASC);
127+
ELSE
128+
INSERT INTO sorts (_field, _dir) VALUES ('id', dir);
129+
END IF;
130+
131+
-- Add value from looked up item to the sorts table
132+
UPDATE sorts SET _val=quote_literal(token_rec->>_field);
133+
134+
-- Check if all sorts are the same direction and use row comparison
135+
-- to filter
136+
RAISE NOTICE 'sorts 2: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
137+
138+
IF (SELECT count(DISTINCT _dir) FROM sorts) = 1 THEN
139+
SELECT format(
140+
'(%s) %s (%s)',
141+
concat_ws(', ', VARIADIC array_agg(quote_ident(_field))),
142+
CASE WHEN (prev AND dir = 'ASC') OR (NOT prev AND dir = 'DESC') THEN '<' ELSE '>' END,
143+
concat_ws(', ', VARIADIC array_agg(_val))
144+
) INTO output FROM sorts
145+
WHERE token_rec ? _field
146+
;
147+
ELSE
148+
FOR sort IN SELECT * FROM sorts ORDER BY _row asc LOOP
149+
RAISE NOTICE 'SORT: %', sort;
150+
IF sort._row = 1 THEN
151+
orfilters := orfilters || format('(%s %s %s)',
152+
quote_ident(sort._field),
153+
CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
154+
sort._val
155+
);
156+
ELSE
157+
orfilters := orfilters || format('(%s AND %s %s %s)',
158+
array_to_string(andfilters, ' AND '),
159+
quote_ident(sort._field),
160+
CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
161+
sort._val
162+
);
163+
164+
END IF;
165+
andfilters := andfilters || format('%s = %s',
166+
quote_ident(sort._field),
167+
sort._val
168+
);
169+
END LOOP;
170+
output := array_to_string(orfilters, ' OR ');
171+
END IF;
172+
DROP TABLE IF EXISTS sorts;
173+
token_where := concat('(',coalesce(output,'true'),')');
174+
IF trim(token_where) = '' THEN
175+
token_where := NULL;
176+
END IF;
177+
RAISE NOTICE 'TOKEN_WHERE: |%|',token_where;
178+
RETURN token_where;
179+
END;
180+
$function$
181+
;
182+
183+
CREATE OR REPLACE FUNCTION pgstac.search(_search jsonb DEFAULT '{}'::jsonb)
184+
RETURNS jsonb
185+
LANGUAGE plpgsql
186+
SET jit TO 'off'
187+
AS $function$
188+
DECLARE
189+
searches searches%ROWTYPE;
190+
_where text;
191+
token_where text;
192+
full_where text;
193+
orderby text;
194+
query text;
195+
token_type text := substr(_search->>'token',1,4);
196+
_limit int := coalesce((_search->>'limit')::int, 10);
197+
curs refcursor;
198+
cntr int := 0;
199+
iter_record items%ROWTYPE;
200+
first_record items%ROWTYPE;
201+
last_record items%ROWTYPE;
202+
out_records jsonb := '[]'::jsonb;
203+
prev_query text;
204+
next text;
205+
prev_id text;
206+
has_next boolean := false;
207+
has_prev boolean := false;
208+
prev text;
209+
total_count bigint;
210+
context jsonb;
211+
collection jsonb;
212+
includes text[];
213+
excludes text[];
214+
exit_flag boolean := FALSE;
215+
batches int := 0;
216+
timer timestamptz := clock_timestamp();
217+
BEGIN
218+
searches := search_query(_search);
219+
_where := searches._where;
220+
orderby := searches.orderby;
221+
total_count := coalesce(searches.total_count, searches.estimated_count);
222+
223+
224+
IF token_type='prev' THEN
225+
token_where := get_token_filter(_search, null::jsonb);
226+
orderby := sort_sqlorderby(_search, TRUE);
227+
END IF;
228+
IF token_type='next' THEN
229+
token_where := get_token_filter(_search, null::jsonb);
230+
END IF;
231+
232+
full_where := concat_ws(' AND ', _where, token_where);
233+
RAISE NOTICE 'FULL QUERY % %', full_where, clock_timestamp()-timer;
234+
timer := clock_timestamp();
235+
236+
FOR query IN SELECT partition_queries(full_where, orderby) LOOP
237+
timer := clock_timestamp();
238+
query := format('%s LIMIT %L', query, _limit + 1);
239+
RAISE NOTICE 'Partition Query: %', query;
240+
batches := batches + 1;
241+
curs = create_cursor(query);
242+
LOOP
243+
FETCH curs into iter_record;
244+
EXIT WHEN NOT FOUND;
245+
cntr := cntr + 1;
246+
last_record := iter_record;
247+
IF cntr = 1 THEN
248+
first_record := last_record;
249+
END IF;
250+
IF cntr <= _limit THEN
251+
out_records := out_records || last_record.content;
252+
ELSIF cntr > _limit THEN
253+
has_next := true;
254+
exit_flag := true;
255+
EXIT;
256+
END IF;
257+
END LOOP;
258+
RAISE NOTICE 'Query took %', clock_timestamp()-timer;
259+
timer := clock_timestamp();
260+
EXIT WHEN exit_flag;
261+
END LOOP;
262+
RAISE NOTICE 'Scanned through % partitions.', batches;
263+
264+
265+
-- Flip things around if this was the result of a prev token query
266+
IF token_type='prev' THEN
267+
out_records := flip_jsonb_array(out_records);
268+
first_record := last_record;
269+
END IF;
270+
271+
-- If this query has a token, see if there is data before the first record
272+
IF _search ? 'token' THEN
273+
prev_query := format(
274+
'SELECT 1 FROM items WHERE %s LIMIT 1',
275+
concat_ws(
276+
' AND ',
277+
_where,
278+
trim(get_token_filter(_search, to_jsonb(first_record)))
279+
)
280+
);
281+
RAISE NOTICE 'Query to get previous record: % --- %', prev_query, first_record;
282+
EXECUTE prev_query INTO has_prev;
283+
IF FOUND and has_prev IS NOT NULL THEN
284+
RAISE NOTICE 'Query results from prev query: %', has_prev;
285+
has_prev := TRUE;
286+
END IF;
287+
END IF;
288+
has_prev := COALESCE(has_prev, FALSE);
289+
290+
RAISE NOTICE 'token_type: %, has_next: %, has_prev: %', token_type, has_next, has_prev;
291+
IF has_prev THEN
292+
prev := out_records->0->>'id';
293+
END IF;
294+
IF has_next OR token_type='prev' THEN
295+
next := out_records->-1->>'id';
296+
END IF;
297+
298+
299+
-- include/exclude any fields following fields extension
300+
IF _search ? 'fields' THEN
301+
IF _search->'fields' ? 'exclude' THEN
302+
excludes=textarr(_search->'fields'->'exclude');
303+
END IF;
304+
IF _search->'fields' ? 'include' THEN
305+
includes=textarr(_search->'fields'->'include');
306+
IF array_length(includes, 1)>0 AND NOT 'id' = ANY (includes) THEN
307+
includes = includes || '{id}';
308+
END IF;
309+
END IF;
310+
SELECT jsonb_agg(filter_jsonb(row, includes, excludes)) INTO out_records FROM jsonb_array_elements(out_records) row;
311+
END IF;
312+
313+
context := jsonb_strip_nulls(jsonb_build_object(
314+
'limit', _limit,
315+
'matched', total_count,
316+
'returned', coalesce(jsonb_array_length(out_records), 0)
317+
));
318+
319+
collection := jsonb_build_object(
320+
'type', 'FeatureCollection',
321+
'features', coalesce(out_records, '[]'::jsonb),
322+
'next', next,
323+
'prev', prev,
324+
'context', context
325+
);
326+
327+
RETURN collection;
328+
END;
329+
$function$
330+
;
331+
332+
CREATE OR REPLACE FUNCTION pgstac.sort_sqlorderby(_search jsonb DEFAULT NULL::jsonb, reverse boolean DEFAULT false)
333+
RETURNS text
334+
LANGUAGE sql
335+
AS $function$
336+
WITH sortby AS (
337+
SELECT coalesce(_search->'sortby','[{"field":"datetime", "direction":"desc"}]') as sort
338+
), withid AS (
339+
SELECT CASE
340+
WHEN sort @? '$[*] ? (@.field == "id")' THEN sort
341+
ELSE sort || '[{"field":"id", "direction":"desc"}]'::jsonb
342+
END as sort
343+
FROM sortby
344+
), withid_rows AS (
345+
SELECT jsonb_array_elements(sort) as value FROM withid
346+
),sorts AS (
347+
SELECT
348+
(items_path(value->>'field')).path as key,
349+
parse_sort_dir(value->>'direction', reverse) as dir
350+
FROM withid_rows
351+
)
352+
SELECT array_to_string(
353+
array_agg(concat(key, ' ', dir)),
354+
', '
355+
) FROM sorts;
356+
$function$
357+
;
358+
359+
360+
361+
INSERT INTO migrations (version) VALUES ('0.3.3');

‎pypgstac/pypgstac/migrations/pgstac.0.3.3.sql

+1,595
Large diffs are not rendered by default.

‎pypgstac/pyproject.toml

+1-1
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,6 @@
11
[tool.poetry]
22
name = "pypgstac"
3-
version = "0.3.2"
3+
version = "0.3.3"
44
description = ""
55
authors = ["David Bitner <bitner@dbspatial.com>"]
66
keywords = ["stac", "asyncpg"]

‎scripts/bin/migra_funcs

+2-2
Original file line numberDiff line numberDiff line change
@@ -45,9 +45,9 @@ export -f pgwait
4545
function pgtap(){
4646
TESTOUTPUT=$(psql -X -f $BASEDIR/test/pgtap.sql $1)
4747
echo "Checking if any tests are not ok on db $1"
48-
if [[ $(echo "$TESTOUTPUT" | grep '^not') == 0 ]]; then
48+
if [[ $(echo "$TESTOUTPUT" | grep -e '^not') ]]; then
4949
echo "PGTap tests failed."
50-
echo "$TESTOUTPUT" | grep '^not'
50+
echo "$TESTOUTPUT"
5151
exit 1
5252
else
5353
echo "All PGTap Tests Passed!"

‎sql/004_search.sql

+111-107
Original file line numberDiff line numberDiff line change
@@ -136,12 +136,12 @@ DECLARE
136136
newprop jsonb;
137137
newprops jsonb := '[]'::jsonb;
138138
BEGIN
139-
IF j ? 'id' THEN
139+
IF j ? 'ids' THEN
140140
newprop := jsonb_build_object(
141141
'in',
142142
jsonb_build_array(
143143
'{"property":"id"}'::jsonb,
144-
j->'id'
144+
j->'ids'
145145
)
146146
);
147147
newprops := jsonb_insert(newprops, '{1}', newprop);
@@ -188,7 +188,7 @@ IF newprops IS NOT NULL AND jsonb_array_length(newprops) > 0 THEN
188188
j,
189189
'{filter}',
190190
cql_and_append(j, jsonb_build_object('and', newprops))
191-
) - '{id,collections,datetime,bbox,intersects}'::text[];
191+
) - '{ids,collections,datetime,bbox,intersects}'::text[];
192192
END IF;
193193

194194
return j;
@@ -499,17 +499,21 @@ CREATE OR REPLACE FUNCTION sort_sqlorderby(
499499
_search jsonb DEFAULT NULL,
500500
reverse boolean DEFAULT FALSE
501501
) RETURNS text AS $$
502-
WITH sorts AS (
502+
WITH sortby AS (
503+
SELECT coalesce(_search->'sortby','[{"field":"datetime", "direction":"desc"}]') as sort
504+
), withid AS (
505+
SELECT CASE
506+
WHEN sort @? '$[*] ? (@.field == "id")' THEN sort
507+
ELSE sort || '[{"field":"id", "direction":"desc"}]'::jsonb
508+
END as sort
509+
FROM sortby
510+
), withid_rows AS (
511+
SELECT jsonb_array_elements(sort) as value FROM withid
512+
),sorts AS (
503513
SELECT
504514
(items_path(value->>'field')).path as key,
505515
parse_sort_dir(value->>'direction', reverse) as dir
506-
FROM jsonb_array_elements(
507-
'[]'::jsonb
508-
||
509-
coalesce(_search->'sortby','[{"field":"datetime", "direction":"desc"}]')
510-
||
511-
'[{"field":"id","direction":"desc"}]'::jsonb
512-
)
516+
FROM withid_rows
513517
)
514518
SELECT array_to_string(
515519
array_agg(concat(key, ' ', dir)),
@@ -524,107 +528,109 @@ $$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
524528

525529
CREATE OR REPLACE FUNCTION get_token_filter(_search jsonb = '{}'::jsonb, token_rec jsonb DEFAULT NULL) RETURNS text AS $$
526530
DECLARE
527-
token_id text;
528-
filters text[] := '{}'::text[];
529-
prev boolean := TRUE;
530-
field text;
531-
dir text;
532-
sort record;
533-
orfilters text[] := '{}'::text[];
534-
andfilters text[] := '{}'::text[];
535-
output text;
536-
token_where text;
531+
token_id text;
532+
filters text[] := '{}'::text[];
533+
prev boolean := TRUE;
534+
field text;
535+
dir text;
536+
sort record;
537+
orfilters text[] := '{}'::text[];
538+
andfilters text[] := '{}'::text[];
539+
output text;
540+
token_where text;
537541
BEGIN
538-
-- If no token provided return NULL
539-
IF token_rec IS NULL THEN
540-
IF NOT (_search ? 'token' AND
541-
(
542-
(_search->>'token' ILIKE 'prev:%')
543-
OR
544-
(_search->>'token' ILIKE 'next:%')
545-
)
546-
) THEN
547-
RETURN NULL;
542+
-- If no token provided return NULL
543+
IF token_rec IS NULL THEN
544+
IF NOT (_search ? 'token' AND
545+
(
546+
(_search->>'token' ILIKE 'prev:%')
547+
OR
548+
(_search->>'token' ILIKE 'next:%')
549+
)
550+
) THEN
551+
RETURN NULL;
552+
END IF;
553+
prev := (_search->>'token' ILIKE 'prev:%');
554+
token_id := substr(_search->>'token', 6);
555+
SELECT to_jsonb(items) INTO token_rec FROM items WHERE id=token_id;
548556
END IF;
549-
prev := (_search->>'token' ILIKE 'prev:%');
550-
token_id := substr(_search->>'token', 6);
551-
SELECT to_jsonb(items) INTO token_rec FROM items WHERE id=token_id;
552-
END IF;
553-
RAISE NOTICE 'TOKEN ID: %', token_rec->'id';
554-
555-
CREATE TEMP TABLE sorts (
556-
_row int GENERATED ALWAYS AS IDENTITY NOT NULL,
557-
_field text PRIMARY KEY,
558-
_dir text NOT NULL,
559-
_val text
560-
) ON COMMIT DROP;
557+
RAISE NOTICE 'TOKEN ID: %', token_rec->'id';
561558

562-
-- Make sure we only have distinct columns to sort with taking the first one we get
563-
INSERT INTO sorts (_field, _dir)
564-
SELECT
565-
(items_path(value->>'field')).path,
566-
get_sort_dir(value)
567-
FROM
568-
jsonb_array_elements(coalesce(_search->'sort','[{"field":"datetime","direction":"desc"}]'))
569-
ON CONFLICT DO NOTHING
570-
;
559+
CREATE TEMP TABLE sorts (
560+
_row int GENERATED ALWAYS AS IDENTITY NOT NULL,
561+
_field text PRIMARY KEY,
562+
_dir text NOT NULL,
563+
_val text
564+
) ON COMMIT DROP;
571565

572-
-- Get the first sort direction provided. As the id is a primary key, if there are any
573-
-- sorts after id they won't do anything, so make sure that id is the last sort item.
574-
SELECT _dir INTO dir FROM sorts ORDER BY _row ASC LIMIT 1;
575-
IF EXISTS (SELECT 1 FROM sorts WHERE _field = 'id') THEN
576-
DELETE FROM sorts WHERE _row > (SELECT _row FROM sorts WHERE _field = 'id');
577-
ELSE
578-
INSERT INTO sorts (_field, _dir) VALUES ('id', dir);
579-
END IF;
580-
581-
-- Add value from looked up item to the sorts table
582-
UPDATE sorts SET _val=quote_literal(token_rec->>_field);
583-
584-
-- Check if all sorts are the same direction and use row comparison
585-
-- to filter
586-
IF (SELECT count(DISTINCT _dir) FROM sorts) = 1 THEN
587-
SELECT format(
588-
'(%s) %s (%s)',
589-
concat_ws(', ', VARIADIC array_agg(quote_ident(_field))),
590-
CASE WHEN (prev AND dir = 'ASC') OR (NOT prev AND dir = 'DESC') THEN '<' ELSE '>' END,
591-
concat_ws(', ', VARIADIC array_agg(_val))
592-
) INTO output FROM sorts
593-
WHERE token_rec ? _field
566+
-- Make sure we only have distinct columns to sort with taking the first one we get
567+
INSERT INTO sorts (_field, _dir)
568+
SELECT
569+
(items_path(value->>'field')).path,
570+
get_sort_dir(value)
571+
FROM
572+
jsonb_array_elements(coalesce(_search->'sortby','[{"field":"datetime","direction":"desc"}]'))
573+
ON CONFLICT DO NOTHING
594574
;
595-
ELSE
596-
FOR sort IN SELECT * FROM sorts ORDER BY _row asc LOOP
597-
RAISE NOTICE 'SORT: %', sort;
598-
IF sort._row = 1 THEN
599-
orfilters := orfilters || format('(%s %s %s)',
600-
quote_ident(sort._field),
601-
CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
602-
sort._val
603-
);
604-
ELSE
605-
orfilters := orfilters || format('(%s AND %s %s %s)',
606-
array_to_string(andfilters, ' AND '),
575+
RAISE NOTICE 'sorts 1: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
576+
-- Get the first sort direction provided. As the id is a primary key, if there are any
577+
-- sorts after id they won't do anything, so make sure that id is the last sort item.
578+
SELECT _dir INTO dir FROM sorts ORDER BY _row ASC LIMIT 1;
579+
IF EXISTS (SELECT 1 FROM sorts WHERE _field = 'id') THEN
580+
DELETE FROM sorts WHERE _row > (SELECT _row FROM sorts WHERE _field = 'id' ORDER BY _row ASC);
581+
ELSE
582+
INSERT INTO sorts (_field, _dir) VALUES ('id', dir);
583+
END IF;
584+
585+
-- Add value from looked up item to the sorts table
586+
UPDATE sorts SET _val=quote_literal(token_rec->>_field);
587+
588+
-- Check if all sorts are the same direction and use row comparison
589+
-- to filter
590+
RAISE NOTICE 'sorts 2: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
591+
592+
IF (SELECT count(DISTINCT _dir) FROM sorts) = 1 THEN
593+
SELECT format(
594+
'(%s) %s (%s)',
595+
concat_ws(', ', VARIADIC array_agg(quote_ident(_field))),
596+
CASE WHEN (prev AND dir = 'ASC') OR (NOT prev AND dir = 'DESC') THEN '<' ELSE '>' END,
597+
concat_ws(', ', VARIADIC array_agg(_val))
598+
) INTO output FROM sorts
599+
WHERE token_rec ? _field
600+
;
601+
ELSE
602+
FOR sort IN SELECT * FROM sorts ORDER BY _row asc LOOP
603+
RAISE NOTICE 'SORT: %', sort;
604+
IF sort._row = 1 THEN
605+
orfilters := orfilters || format('(%s %s %s)',
606+
quote_ident(sort._field),
607+
CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
608+
sort._val
609+
);
610+
ELSE
611+
orfilters := orfilters || format('(%s AND %s %s %s)',
612+
array_to_string(andfilters, ' AND '),
613+
quote_ident(sort._field),
614+
CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
615+
sort._val
616+
);
617+
618+
END IF;
619+
andfilters := andfilters || format('%s = %s',
607620
quote_ident(sort._field),
608-
CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
609621
sort._val
610622
);
611-
612-
END IF;
613-
andfilters := andfilters || format('%s = %s',
614-
quote_ident(sort._field),
615-
sort._val
616-
);
617-
END LOOP;
618-
output := array_to_string(orfilters, ' OR ');
619-
END IF;
620-
DROP TABLE IF EXISTS sorts;
621-
token_where := concat('(',coalesce(output,'true'),')');
622-
IF trim(token_where) = '' THEN
623-
token_where := NULL;
624-
END IF;
625-
RAISE NOTICE 'TOKEN_WHERE: |%|',token_where;
626-
RETURN token_where;
627-
END;
623+
END LOOP;
624+
output := array_to_string(orfilters, ' OR ');
625+
END IF;
626+
DROP TABLE IF EXISTS sorts;
627+
token_where := concat('(',coalesce(output,'true'),')');
628+
IF trim(token_where) = '' THEN
629+
token_where := NULL;
630+
END IF;
631+
RAISE NOTICE 'TOKEN_WHERE: |%|',token_where;
632+
RETURN token_where;
633+
END;
628634
$$ LANGUAGE PLPGSQL;
629635

630636
CREATE OR REPLACE FUNCTION search_tohash(jsonb) RETURNS jsonb AS $$
@@ -821,7 +827,6 @@ IF has_next OR token_type='prev' THEN
821827
END IF;
822828

823829

824-
825830
-- include/exclude any fields following fields extension
826831
IF _search ? 'fields' THEN
827832
IF _search->'fields' ? 'exclude' THEN
@@ -836,7 +841,6 @@ IF _search ? 'fields' THEN
836841
SELECT jsonb_agg(filter_jsonb(row, includes, excludes)) INTO out_records FROM jsonb_array_elements(out_records) row;
837842
END IF;
838843

839-
840844
context := jsonb_strip_nulls(jsonb_build_object(
841845
'limit', _limit,
842846
'matched', total_count,
@@ -845,7 +849,7 @@ context := jsonb_strip_nulls(jsonb_build_object(
845849

846850
collection := jsonb_build_object(
847851
'type', 'FeatureCollection',
848-
'features', out_records,
852+
'features', coalesce(out_records, '[]'::jsonb),
849853
'next', next,
850854
'prev', prev,
851855
'context', context

‎sql/999_version.sql

+1-1
Original file line numberDiff line numberDiff line change
@@ -1 +1 @@
1-
INSERT INTO pgstac.migrations (version) VALUES ('0.3.2');
1+
INSERT INTO pgstac.migrations (version) VALUES ('0.3.3');

‎test/pgtap.sql

+1-1
Original file line numberDiff line numberDiff line change
@@ -19,7 +19,7 @@ SET SEARCH_PATH TO pgstac, pgtap, public;
1919
SET CLIENT_MIN_MESSAGES TO 'warning';
2020

2121
-- Plan the tests.
22-
SELECT plan(70);
22+
SELECT plan(77);
2323
--SELECT * FROM no_plan();
2424

2525
-- Run the tests.

‎test/pgtap/004_search.sql

+29-4
Original file line numberDiff line numberDiff line change
@@ -25,15 +25,15 @@ SELECT results_eq($$ SELECT bbox_geom('[0,1,2,3,4,5]'::jsonb) $$, $$ SELECT '010
2525
SELECT has_function('pgstac'::name, 'add_filters_to_cql', ARRAY['jsonb']);
2626

2727
SELECT results_eq($$
28-
SELECT add_filters_to_cql('{"id":["a","b"]}'::jsonb);
28+
SELECT add_filters_to_cql('{"ids":["a","b"]}'::jsonb);
2929
$$,$$
3030
SELECT '{"filter":{"and": [{"in": [{"property": "id"}, ["a", "b"]]}]}}'::jsonb;
3131
$$,
3232
'Test that id gets added to cql filter when cql filter does not exist'
3333
);
3434

3535
SELECT results_eq($$
36-
SELECT add_filters_to_cql('{"id":["a","b"],"filter":{"and":[{"eq":[1,1]}]}}'::jsonb);
36+
SELECT add_filters_to_cql('{"ids":["a","b"],"filter":{"and":[{"eq":[1,1]}]}}'::jsonb);
3737
$$,$$
3838
SELECT '{"filter":{"and": [{"and": [{"eq": [1, 1]}]}, {"and": [{"in": [{"property": "id"}, ["a", "b"]]}]}]}}'::jsonb;
3939
$$,
@@ -154,12 +154,29 @@ SELECT results_eq($$
154154
'Test lt as a filter on a numeric field with order by'
155155
);
156156

157+
SELECT results_eq($$
158+
select s from search('{"ids":["pgstac-test-item-0097"],"fields":{"include":["id"]}}') s;
159+
$$,$$
160+
select '{"next": null, "prev": null, "type": "FeatureCollection", "context": {"limit": 10, "matched": 1, "returned": 1}, "features": [{"id": "pgstac-test-item-0097"}]}'::jsonb
161+
$$,
162+
'Test ids search single'
163+
);
164+
165+
SELECT results_eq($$
166+
select s from search('{"ids":["pgstac-test-item-0097","pgstac-test-item-0003"],"fields":{"include":["id"]}}') s;
167+
$$,$$
168+
select '{"next": null, "prev": null, "type": "FeatureCollection", "context": {"limit": 10, "matched": 2, "returned": 2}, "features": [{"id": "pgstac-test-item-0003"},{"id": "pgstac-test-item-0097"}]}'::jsonb
169+
$$,
170+
'Test ids search multi'
171+
);
172+
173+
157174
SELECT results_eq($$
158175
select s from search('{"collections":["pgstac-test-collection"],"fields":{"include":["id"]}, "limit": 1}') s;
159176
$$,$$
160-
select '{"next": "20200307aC0870130w361200", "prev": null, "type": "FeatureCollection", "context": {"limit": 1, "matched": 100, "returned": 1}, "features": [{"id": "20200307aC0870130w361200"}]}'::jsonb
177+
select '{"next": "pgstac-test-item-0003", "prev": null, "type": "FeatureCollection", "context": {"limit": 1, "matched": 100, "returned": 1}, "features": [{"id": "pgstac-test-item-0003"}]}'::jsonb
161178
$$,
162-
'Test collections search with unknow collection'
179+
'Test collections search'
163180
);
164181

165182
SELECT results_eq($$
@@ -170,6 +187,14 @@ SELECT results_eq($$
170187
'Test collections search with unknow collection'
171188
);
172189

190+
SELECT results_eq($$
191+
select s from search('{"collections":["something"],"fields":{"include":["id"]}}') s;
192+
$$,$$
193+
select '{"next": null, "prev": null, "type": "FeatureCollection", "context": {"limit": 10, "matched": 0, "returned": 0}, "features": []}'::jsonb
194+
$$,
195+
'Test collections search return empty feature not null'
196+
);
197+
173198
/* template
174199
SELECT results_eq($$
175200

0 commit comments

Comments
 (0)
Please sign in to comment.