Skip to content

Commit 29a94e1

Browse files
authoredMay 31, 2023
fix for #182 (#183)
* fix for #182 * add metadata to tests
1 parent 3685609 commit 29a94e1

File tree

8 files changed

+4358
-9
lines changed

8 files changed

+4358
-9
lines changed
 

‎CHANGELOG.md

+5
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,11 @@ 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.7.8]
8+
9+
### Fixed
10+
- Fix issue with search_query not returning all fields on first use of a query. Fixes #182
11+
712
## [v0.7.7]
813

914
### Fixed
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,282 @@
1+
RESET ROLE;
2+
DO $$
3+
DECLARE
4+
BEGIN
5+
IF NOT EXISTS (SELECT 1 FROM pg_extension WHERE extname='postgis') THEN
6+
CREATE EXTENSION IF NOT EXISTS postgis;
7+
END IF;
8+
IF NOT EXISTS (SELECT 1 FROM pg_extension WHERE extname='btree_gist') THEN
9+
CREATE EXTENSION IF NOT EXISTS btree_gist;
10+
END IF;
11+
END;
12+
$$ LANGUAGE PLPGSQL;
13+
14+
DO $$
15+
BEGIN
16+
CREATE ROLE pgstac_admin;
17+
EXCEPTION WHEN duplicate_object THEN
18+
RAISE NOTICE '%, skipping', SQLERRM USING ERRCODE = SQLSTATE;
19+
END
20+
$$;
21+
22+
DO $$
23+
BEGIN
24+
CREATE ROLE pgstac_read;
25+
EXCEPTION WHEN duplicate_object THEN
26+
RAISE NOTICE '%, skipping', SQLERRM USING ERRCODE = SQLSTATE;
27+
END
28+
$$;
29+
30+
DO $$
31+
BEGIN
32+
CREATE ROLE pgstac_ingest;
33+
EXCEPTION WHEN duplicate_object THEN
34+
RAISE NOTICE '%, skipping', SQLERRM USING ERRCODE = SQLSTATE;
35+
END
36+
$$;
37+
38+
39+
GRANT pgstac_admin TO current_user;
40+
41+
-- Function to make sure pgstac_admin is the owner of items
42+
CREATE OR REPLACE FUNCTION pgstac_admin_owns() RETURNS VOID AS $$
43+
DECLARE
44+
f RECORD;
45+
BEGIN
46+
FOR f IN (
47+
SELECT
48+
concat(
49+
oid::regproc::text,
50+
'(',
51+
coalesce(pg_get_function_identity_arguments(oid),''),
52+
')'
53+
) AS name,
54+
CASE prokind WHEN 'f' THEN 'FUNCTION' WHEN 'p' THEN 'PROCEDURE' WHEN 'a' THEN 'AGGREGATE' END as typ
55+
FROM pg_proc
56+
WHERE
57+
pronamespace=to_regnamespace('pgstac')
58+
AND proowner != to_regrole('pgstac_admin')
59+
AND proname NOT LIKE 'pg_stat%'
60+
)
61+
LOOP
62+
BEGIN
63+
EXECUTE format('ALTER %s %s OWNER TO pgstac_admin;', f.typ, f.name);
64+
EXCEPTION WHEN others THEN
65+
RAISE NOTICE '%, skipping', SQLERRM USING ERRCODE = SQLSTATE;
66+
END;
67+
END LOOP;
68+
FOR f IN (
69+
SELECT
70+
oid::regclass::text as name,
71+
CASE relkind
72+
WHEN 'i' THEN 'INDEX'
73+
WHEN 'I' THEN 'INDEX'
74+
WHEN 'p' THEN 'TABLE'
75+
WHEN 'r' THEN 'TABLE'
76+
WHEN 'v' THEN 'VIEW'
77+
WHEN 'S' THEN 'SEQUENCE'
78+
ELSE NULL
79+
END as typ
80+
FROM pg_class
81+
WHERE relnamespace=to_regnamespace('pgstac') and relowner != to_regrole('pgstac_admin') AND relkind IN ('r','p','v','S') AND relname NOT LIKE 'pg_stat'
82+
)
83+
LOOP
84+
BEGIN
85+
EXECUTE format('ALTER %s %s OWNER TO pgstac_admin;', f.typ, f.name);
86+
EXCEPTION WHEN others THEN
87+
RAISE NOTICE '%, skipping', SQLERRM USING ERRCODE = SQLSTATE;
88+
END;
89+
END LOOP;
90+
RETURN;
91+
END;
92+
$$ LANGUAGE PLPGSQL;
93+
SELECT pgstac_admin_owns();
94+
95+
CREATE SCHEMA IF NOT EXISTS pgstac AUTHORIZATION pgstac_admin;
96+
97+
GRANT ALL ON ALL FUNCTIONS IN SCHEMA pgstac to pgstac_admin;
98+
GRANT ALL ON ALL TABLES IN SCHEMA pgstac to pgstac_admin;
99+
GRANT ALL ON ALL SEQUENCES IN SCHEMA pgstac to pgstac_admin;
100+
101+
ALTER ROLE pgstac_admin SET SEARCH_PATH TO pgstac, public;
102+
ALTER ROLE pgstac_read SET SEARCH_PATH TO pgstac, public;
103+
ALTER ROLE pgstac_ingest SET SEARCH_PATH TO pgstac, public;
104+
105+
GRANT USAGE ON SCHEMA pgstac to pgstac_read;
106+
ALTER DEFAULT PRIVILEGES IN SCHEMA pgstac GRANT SELECT ON TABLES TO pgstac_read;
107+
ALTER DEFAULT PRIVILEGES IN SCHEMA pgstac GRANT USAGE ON TYPES TO pgstac_read;
108+
ALTER DEFAULT PRIVILEGES IN SCHEMA pgstac GRANT ALL ON SEQUENCES TO pgstac_read;
109+
110+
GRANT pgstac_read TO pgstac_ingest;
111+
GRANT ALL ON SCHEMA pgstac TO pgstac_ingest;
112+
ALTER DEFAULT PRIVILEGES IN SCHEMA pgstac GRANT ALL ON TABLES TO pgstac_ingest;
113+
ALTER DEFAULT PRIVILEGES IN SCHEMA pgstac GRANT ALL ON FUNCTIONS TO pgstac_ingest;
114+
115+
SET ROLE pgstac_admin;
116+
117+
SET SEARCH_PATH TO pgstac, public;
118+
119+
DO $$
120+
BEGIN
121+
DROP FUNCTION IF EXISTS analyze_items;
122+
EXCEPTION WHEN others THEN
123+
RAISE NOTICE '%, skipping', SQLERRM USING ERRCODE = SQLSTATE;
124+
END
125+
$$;
126+
DO $$
127+
BEGIN
128+
DROP FUNCTION IF EXISTS validate_constraints;
129+
EXCEPTION WHEN others THEN
130+
RAISE NOTICE '%, skipping', SQLERRM USING ERRCODE = SQLSTATE;
131+
END
132+
$$;
133+
SET client_min_messages TO WARNING;
134+
SET SEARCH_PATH to pgstac, public;
135+
-- BEGIN migra calculated SQL
136+
set check_function_bodies = off;
137+
138+
CREATE OR REPLACE FUNCTION pgstac.search_query(_search jsonb DEFAULT '{}'::jsonb, updatestats boolean DEFAULT false, _metadata jsonb DEFAULT '{}'::jsonb)
139+
RETURNS pgstac.searches
140+
LANGUAGE plpgsql
141+
SECURITY DEFINER
142+
AS $function$
143+
DECLARE
144+
search searches%ROWTYPE;
145+
pexplain jsonb;
146+
t timestamptz;
147+
i interval;
148+
_hash text := search_hash(_search, _metadata);
149+
doupdate boolean := FALSE;
150+
insertfound boolean := FALSE;
151+
BEGIN
152+
SELECT * INTO search FROM searches
153+
WHERE hash=_hash;
154+
155+
search.hash := _hash;
156+
157+
-- Calculate the where clause if not already calculated
158+
IF search._where IS NULL THEN
159+
search._where := stac_search_to_where(_search);
160+
ELSE
161+
doupdate := TRUE;
162+
END IF;
163+
164+
-- Calculate the order by clause if not already calculated
165+
IF search.orderby IS NULL THEN
166+
search.orderby := sort_sqlorderby(_search);
167+
ELSE
168+
doupdate := TRUE;
169+
END IF;
170+
171+
PERFORM where_stats(search._where, updatestats, _search->'conf');
172+
173+
IF NOT doupdate THEN
174+
INSERT INTO searches (search, _where, orderby, lastused, usecount, metadata)
175+
VALUES (_search, search._where, search.orderby, clock_timestamp(), 1, _metadata)
176+
ON CONFLICT (hash) DO NOTHING RETURNING * INTO search;
177+
IF FOUND THEN
178+
RETURN search;
179+
END IF;
180+
END IF;
181+
182+
UPDATE searches
183+
SET
184+
lastused=clock_timestamp(),
185+
usecount=usecount+1
186+
WHERE hash=(
187+
SELECT hash FROM searches
188+
WHERE hash=_hash
189+
FOR UPDATE SKIP LOCKED
190+
);
191+
IF NOT FOUND THEN
192+
RAISE NOTICE 'Did not update stats for % due to lock. (This is generally OK)', _search;
193+
END IF;
194+
195+
RETURN search;
196+
197+
END;
198+
$function$
199+
;
200+
201+
202+
203+
-- END migra calculated SQL
204+
DO $$
205+
BEGIN
206+
INSERT INTO queryables (name, definition, property_wrapper, property_index_type) VALUES
207+
('id', '{"title": "Item ID","description": "Item identifier","$ref": "https://schemas.stacspec.org/v1.0.0/item-spec/json-schema/item.json#/definitions/core/allOf/2/properties/id"}', null, null);
208+
EXCEPTION WHEN unique_violation THEN
209+
RAISE NOTICE '%', SQLERRM USING ERRCODE = SQLSTATE;
210+
END
211+
$$;
212+
213+
DO $$
214+
BEGIN
215+
INSERT INTO queryables (name, definition, property_wrapper, property_index_type) VALUES
216+
('geometry', '{"title": "Item Geometry","description": "Item Geometry","$ref": "https://geojson.org/schema/Feature.json"}', null, null);
217+
EXCEPTION WHEN unique_violation THEN
218+
RAISE NOTICE '%', SQLERRM USING ERRCODE = SQLSTATE;
219+
END
220+
$$;
221+
222+
DO $$
223+
BEGIN
224+
INSERT INTO queryables (name, definition, property_wrapper, property_index_type) VALUES
225+
('datetime','{"description": "Datetime","type": "string","title": "Acquired","format": "date-time","pattern": "(\\+00:00|Z)$"}', null, null);
226+
EXCEPTION WHEN unique_violation THEN
227+
RAISE NOTICE '%', SQLERRM USING ERRCODE = SQLSTATE;
228+
END
229+
$$;
230+
231+
DO $$
232+
BEGIN
233+
INSERT INTO queryables (name, definition, property_wrapper, property_index_type) VALUES
234+
('eo:cloud_cover','{"$ref": "https://stac-extensions.github.io/eo/v1.0.0/schema.json#/definitions/fieldsproperties/eo:cloud_cover"}','to_int','BTREE');
235+
EXCEPTION WHEN unique_violation THEN
236+
RAISE NOTICE '%', SQLERRM USING ERRCODE = SQLSTATE;
237+
END
238+
$$;
239+
240+
DELETE FROM queryables a USING queryables b
241+
WHERE a.name = b.name AND a.collection_ids IS NOT DISTINCT FROM b.collection_ids AND a.id > b.id;
242+
243+
244+
INSERT INTO pgstac_settings (name, value) VALUES
245+
('context', 'off'),
246+
('context_estimated_count', '100000'),
247+
('context_estimated_cost', '100000'),
248+
('context_stats_ttl', '1 day'),
249+
('default_filter_lang', 'cql2-json'),
250+
('additional_properties', 'true'),
251+
('use_queue', 'false'),
252+
('queue_timeout', '10 minutes'),
253+
('update_collection_extent', 'false'),
254+
('format_cache', 'false')
255+
ON CONFLICT DO NOTHING
256+
;
257+
258+
ALTER FUNCTION to_text COST 5000;
259+
ALTER FUNCTION to_float COST 5000;
260+
ALTER FUNCTION to_int COST 5000;
261+
ALTER FUNCTION to_tstz COST 5000;
262+
ALTER FUNCTION to_text_array COST 5000;
263+
264+
265+
GRANT USAGE ON SCHEMA pgstac to pgstac_read;
266+
GRANT ALL ON SCHEMA pgstac to pgstac_ingest;
267+
GRANT ALL ON SCHEMA pgstac to pgstac_admin;
268+
269+
-- pgstac_read role limited to using function apis
270+
GRANT EXECUTE ON FUNCTION search TO pgstac_read;
271+
GRANT EXECUTE ON FUNCTION search_query TO pgstac_read;
272+
GRANT EXECUTE ON FUNCTION item_by_id TO pgstac_read;
273+
GRANT EXECUTE ON FUNCTION get_item TO pgstac_read;
274+
GRANT SELECT ON ALL TABLES IN SCHEMA pgstac TO pgstac_read;
275+
276+
277+
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA pgstac to pgstac_ingest;
278+
GRANT ALL ON ALL TABLES IN SCHEMA pgstac to pgstac_ingest;
279+
GRANT USAGE ON ALL SEQUENCES IN SCHEMA pgstac to pgstac_ingest;
280+
281+
SELECT update_partition_stats_q(partition) FROM partitions_view;
282+
SELECT set_version('0.7.8');

‎src/pgstac/migrations/pgstac.0.7.8.sql

+4,052
Large diffs are not rendered by default.

‎src/pgstac/sql/004_search.sql

+1-1
Original file line numberDiff line numberDiff line change
@@ -592,7 +592,7 @@ BEGIN
592592
IF NOT doupdate THEN
593593
INSERT INTO searches (search, _where, orderby, lastused, usecount, metadata)
594594
VALUES (_search, search._where, search.orderby, clock_timestamp(), 1, _metadata)
595-
ON CONFLICT (hash) DO NOTHING;
595+
ON CONFLICT (hash) DO NOTHING RETURNING * INTO search;
596596
IF FOUND THEN
597597
RETURN search;
598598
END IF;

‎src/pgstac/sql/999_version.sql

+1-1
Original file line numberDiff line numberDiff line change
@@ -1 +1 @@
1-
SELECT set_version('0.7.7');
1+
SELECT set_version('0.7.8');

‎src/pgstac/tests/basic/cql_searches.sql

+6-2
Original file line numberDiff line numberDiff line change
@@ -36,6 +36,10 @@ SELECT search('{"collections":["something"]}');
3636

3737
SELECT search('{"collections":["something"],"fields":{"include":["id"]}}');
3838

39-
SELECT hash from search_query('{"collections":["pgstac-test-collection"]}');
39+
SELECT usecount IS NOT NULL and usecount > 0 AND lastused IS NOT NULL AND lastused < clock_timestamp() FROM search_query(jsonb_build_object('collections',ARRAY[random()::text]));
4040

41-
SELECT search from search_query('{"collections":["pgstac-test-collection"]}');
41+
SELECT hash, search, _where, orderby, metadata from search_query('{"collections":["pgstac-test-collection"]}'::jsonb, _metadata=>'{"meta":"value"}'::jsonb);
42+
43+
SELECT hash, search, _where, orderby, metadata from search_query('{"collections":["pgstac-test-collection"]}'::jsonb, _metadata=>'{"meta":"value"}'::jsonb);
44+
45+
SELECT usecount IS NOT NULL and usecount > 0 AND lastused IS NOT NULL AND lastused < clock_timestamp() FROM search_query('{"collections":["pgstac-test-collection"]}');

‎src/pgstac/tests/basic/cql_searches.sql.out

+10-4
Original file line numberDiff line numberDiff line change
@@ -53,8 +53,14 @@ SELECT search('{"collections":["something"]}');
5353
SELECT search('{"collections":["something"],"fields":{"include":["id"]}}');
5454
{"next": null, "prev": null, "type": "FeatureCollection", "context": {"limit": 10, "matched": 0, "returned": 0}, "features": []}
5555

56-
SELECT hash from search_query('{"collections":["pgstac-test-collection"]}');
57-
2bbae9a0ef0bbb5ffaca06603ce621d7
56+
SELECT usecount IS NOT NULL and usecount > 0 AND lastused IS NOT NULL AND lastused < clock_timestamp() FROM search_query(jsonb_build_object('collections',ARRAY[random()::text]));
57+
t
5858

59-
SELECT search from search_query('{"collections":["pgstac-test-collection"]}');
60-
{"collections": ["pgstac-test-collection"]}
59+
SELECT hash, search, _where, orderby, metadata from search_query('{"collections":["pgstac-test-collection"]}'::jsonb, _metadata=>'{"meta":"value"}'::jsonb);
60+
06efe6c09f0d61fd212e882325041a73 | {"collections": ["pgstac-test-collection"]} | collection = ANY ('{pgstac-test-collection}') | datetime DESC, id DESC | {"meta": "value"}
61+
62+
SELECT hash, search, _where, orderby, metadata from search_query('{"collections":["pgstac-test-collection"]}'::jsonb, _metadata=>'{"meta":"value"}'::jsonb);
63+
06efe6c09f0d61fd212e882325041a73 | {"collections": ["pgstac-test-collection"]} | collection = ANY ('{pgstac-test-collection}') | datetime DESC, id DESC | {"meta": "value"}
64+
65+
SELECT usecount IS NOT NULL and usecount > 0 AND lastused IS NOT NULL AND lastused < clock_timestamp() FROM search_query('{"collections":["pgstac-test-collection"]}');
66+
t

‎src/pypgstac/pypgstac/version.py

+1-1
Original file line numberDiff line numberDiff line change
@@ -1,2 +1,2 @@
11
"""Version."""
2-
__version__ = "0.7.7"
2+
__version__ = "0.7.8"

0 commit comments

Comments
 (0)
Please sign in to comment.