Skip to content

Commit 6422105

Browse files
authored
fix for paging and sorting (#154)
1 parent 4aba080 commit 6422105

File tree

6 files changed

+3442
-5
lines changed

6 files changed

+3442
-5
lines changed

CHANGELOG.md

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,12 @@ All notable changes to this project will be documented in this file.
44
The format is based on [Keep a Changelog](http://keepachangelog.com/)
55
and this project adheres to [Semantic Versioning](http://semver.org/).
66

7+
## [v0.6.13]
8+
9+
### Fixed
10+
- Fix issue with sorting and paging where in some circumstances the aggregation of data changed the expected order
11+
12+
713
## [v0.6.12]
814

915
### Added
Lines changed: 196 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,196 @@
1+
SET client_min_messages TO WARNING;
2+
SET SEARCH_PATH to pgstac, public;
3+
set check_function_bodies = off;
4+
5+
CREATE OR REPLACE FUNCTION pgstac.search(_search jsonb DEFAULT '{}'::jsonb)
6+
RETURNS jsonb
7+
LANGUAGE plpgsql
8+
SECURITY DEFINER
9+
SET search_path TO 'pgstac', 'public'
10+
SET cursor_tuple_fraction TO '1'
11+
AS $function$
12+
DECLARE
13+
searches searches%ROWTYPE;
14+
_where text;
15+
token_where text;
16+
full_where text;
17+
orderby text;
18+
query text;
19+
token_type text := substr(_search->>'token',1,4);
20+
_limit int := coalesce((_search->>'limit')::int, 10);
21+
curs refcursor;
22+
cntr int := 0;
23+
iter_record items%ROWTYPE;
24+
first_record jsonb;
25+
first_item items%ROWTYPE;
26+
last_item items%ROWTYPE;
27+
last_record jsonb;
28+
out_records jsonb := '[]'::jsonb;
29+
prev_query text;
30+
next text;
31+
prev_id text;
32+
has_next boolean := false;
33+
has_prev boolean := false;
34+
prev text;
35+
total_count bigint;
36+
context jsonb;
37+
collection jsonb;
38+
includes text[];
39+
excludes text[];
40+
exit_flag boolean := FALSE;
41+
batches int := 0;
42+
timer timestamptz := clock_timestamp();
43+
pstart timestamptz;
44+
pend timestamptz;
45+
pcurs refcursor;
46+
search_where search_wheres%ROWTYPE;
47+
id text;
48+
BEGIN
49+
CREATE TEMP TABLE results (i int GENERATED ALWAYS AS IDENTITY, content jsonb) ON COMMIT DROP;
50+
-- if ids is set, short circuit and just use direct ids query for each id
51+
-- skip any paging or caching
52+
-- hard codes ordering in the same order as the array of ids
53+
IF _search ? 'ids' THEN
54+
INSERT INTO results (content)
55+
SELECT
56+
CASE WHEN _search->'conf'->>'nohydrate' IS NOT NULL AND (_search->'conf'->>'nohydrate')::boolean = true THEN
57+
content_nonhydrated(items, _search->'fields')
58+
ELSE
59+
content_hydrate(items, _search->'fields')
60+
END
61+
FROM items WHERE
62+
items.id = ANY(to_text_array(_search->'ids'))
63+
AND
64+
CASE WHEN _search ? 'collections' THEN
65+
items.collection = ANY(to_text_array(_search->'collections'))
66+
ELSE TRUE
67+
END
68+
ORDER BY items.datetime desc, items.id desc
69+
;
70+
SELECT INTO total_count count(*) FROM results;
71+
ELSE
72+
searches := search_query(_search);
73+
_where := searches._where;
74+
orderby := searches.orderby;
75+
search_where := where_stats(_where);
76+
total_count := coalesce(search_where.total_count, search_where.estimated_count);
77+
78+
IF token_type='prev' THEN
79+
token_where := get_token_filter(_search, null::jsonb);
80+
orderby := sort_sqlorderby(_search, TRUE);
81+
END IF;
82+
IF token_type='next' THEN
83+
token_where := get_token_filter(_search, null::jsonb);
84+
END IF;
85+
86+
full_where := concat_ws(' AND ', _where, token_where);
87+
RAISE NOTICE 'FULL QUERY % %', full_where, clock_timestamp()-timer;
88+
timer := clock_timestamp();
89+
90+
FOR query IN SELECT partition_queries(full_where, orderby, search_where.partitions) LOOP
91+
timer := clock_timestamp();
92+
query := format('%s LIMIT %s', query, _limit + 1);
93+
RAISE NOTICE 'Partition Query: %', query;
94+
batches := batches + 1;
95+
-- curs = create_cursor(query);
96+
RAISE NOTICE 'cursor_tuple_fraction: %', current_setting('cursor_tuple_fraction');
97+
OPEN curs FOR EXECUTE query;
98+
LOOP
99+
FETCH curs into iter_record;
100+
EXIT WHEN NOT FOUND;
101+
cntr := cntr + 1;
102+
103+
IF _search->'conf'->>'nohydrate' IS NOT NULL AND (_search->'conf'->>'nohydrate')::boolean = true THEN
104+
last_record := content_nonhydrated(iter_record, _search->'fields');
105+
ELSE
106+
last_record := content_hydrate(iter_record, _search->'fields');
107+
END IF;
108+
last_item := iter_record;
109+
IF cntr = 1 THEN
110+
first_item := last_item;
111+
first_record := last_record;
112+
END IF;
113+
IF cntr <= _limit THEN
114+
INSERT INTO results (content) VALUES (last_record);
115+
ELSIF cntr > _limit THEN
116+
has_next := true;
117+
exit_flag := true;
118+
EXIT;
119+
END IF;
120+
END LOOP;
121+
CLOSE curs;
122+
RAISE NOTICE 'Query took %.', clock_timestamp()-timer;
123+
timer := clock_timestamp();
124+
EXIT WHEN exit_flag;
125+
END LOOP;
126+
RAISE NOTICE 'Scanned through % partitions.', batches;
127+
END IF;
128+
129+
WITH ordered AS (SELECT * FROM results WHERE content IS NOT NULL ORDER BY i)
130+
SELECT jsonb_agg(content) INTO out_records FROM ordered;
131+
132+
DROP TABLE results;
133+
134+
135+
-- Flip things around if this was the result of a prev token query
136+
IF token_type='prev' THEN
137+
out_records := flip_jsonb_array(out_records);
138+
first_item := last_item;
139+
first_record := last_record;
140+
END IF;
141+
142+
-- If this query has a token, see if there is data before the first record
143+
IF _search ? 'token' THEN
144+
prev_query := format(
145+
'SELECT 1 FROM items WHERE %s LIMIT 1',
146+
concat_ws(
147+
' AND ',
148+
_where,
149+
trim(get_token_filter(_search, to_jsonb(first_item)))
150+
)
151+
);
152+
RAISE NOTICE 'Query to get previous record: % --- %', prev_query, first_record;
153+
EXECUTE prev_query INTO has_prev;
154+
IF FOUND and has_prev IS NOT NULL THEN
155+
RAISE NOTICE 'Query results from prev query: %', has_prev;
156+
has_prev := TRUE;
157+
END IF;
158+
END IF;
159+
has_prev := COALESCE(has_prev, FALSE);
160+
161+
IF has_prev THEN
162+
prev := out_records->0->>'id';
163+
END IF;
164+
IF has_next OR token_type='prev' THEN
165+
next := out_records->-1->>'id';
166+
END IF;
167+
168+
IF context(_search->'conf') != 'off' THEN
169+
context := jsonb_strip_nulls(jsonb_build_object(
170+
'limit', _limit,
171+
'matched', total_count,
172+
'returned', coalesce(jsonb_array_length(out_records), 0)
173+
));
174+
ELSE
175+
context := jsonb_strip_nulls(jsonb_build_object(
176+
'limit', _limit,
177+
'returned', coalesce(jsonb_array_length(out_records), 0)
178+
));
179+
END IF;
180+
181+
collection := jsonb_build_object(
182+
'type', 'FeatureCollection',
183+
'features', coalesce(out_records, '[]'::jsonb),
184+
'next', next,
185+
'prev', prev,
186+
'context', context
187+
);
188+
189+
RETURN collection;
190+
END;
191+
$function$
192+
;
193+
194+
195+
196+
SELECT set_version('0.6.13');

0 commit comments

Comments
 (0)