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