Skip to content

Commit 7f9c750

Browse files
mmcfarlandbitner
andauthored
Fix collection check in queryable trigger_func (#179)
* Fix collection existence check in queryables The previous check for the existence of a collection could still return values that weren't in the new collection_ids array. This issue was only present when there were more collections than just the collection being tested. I added an additional test collection, added a test to verify the error and then updated the sql join to only return results if there is a missing collection. * Update queryable docs to account for text[] Use a more specific query to correctly insert queryables from `missing_queryables` * migration * Changelog --------- Co-authored-by: David Bitner <[email protected]>
1 parent c01364d commit 7f9c750

File tree

10 files changed

+4350
-11
lines changed

10 files changed

+4350
-11
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.6]
8+
9+
### Fixed
10+
- Fix issue with checking for existing collections in queryable trigger function that prevented adding scoped queryable entries.
11+
712
## [v0.7.5]
813

914
### Fixed

docs/src/pgstac.md

+4-2
Original file line numberDiff line numberDiff line change
@@ -137,10 +137,12 @@ SELECT * FROM missing_queryables(5);
137137
138138
The numeric argument is the approximate percent of items that should be sampled to look for fields to include. This function will look for fields in the properties of items that do not already exist in the queryables table for each collection. It will then look to see if there is a field in any definition in the stac_extensions table to populate the definition for the queryable. If no definition was found, it will use the data type of the values for that field in the sample of items to fill in a generic definition with just the field type.
139139
140-
In order to populate the queryables table, you can then run:
140+
In order to populate the queryables table, you can then run the following query. Note we're casting the collection id to a text array:
141141

142142
```sql
143-
INSERT INTO queryables (collection_ids, name, definition, property_wrapper) SELECT * FROM missing_queryables(5);
143+
INSERT INTO queryables (collection_ids, name, definition, property_wrapper)
144+
SELECT array[collection]::text[] as collection_ids, name, definition, property_wrapper
145+
FROM missing_queryables('mycollection', 5)
144146
```
145147

146148
If you run into conflicts due to the unique constraints on collection/name, you may need to create a temp table, make any changes to remove the conflicts, and then INSERT.
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,302 @@
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.queryables_constraint_triggerfunc()
139+
RETURNS trigger
140+
LANGUAGE plpgsql
141+
AS $function$
142+
DECLARE
143+
allcollections text[];
144+
BEGIN
145+
RAISE NOTICE 'Making sure that name/collection is unique for queryables %', NEW;
146+
IF NEW.collection_ids IS NOT NULL THEN
147+
IF EXISTS (
148+
SELECT 1
149+
FROM unnest(NEW.collection_ids) c
150+
LEFT JOIN
151+
collections
152+
ON (collections.id = c)
153+
WHERE collections.id IS NULL
154+
) THEN
155+
RAISE foreign_key_violation USING MESSAGE = format(
156+
'One or more collections in %s do not exist.', NEW.collection_ids
157+
);
158+
RETURN NULL;
159+
END IF;
160+
END IF;
161+
IF TG_OP = 'INSERT' THEN
162+
IF EXISTS (
163+
SELECT 1 FROM queryables q
164+
WHERE
165+
q.name = NEW.name
166+
AND (
167+
q.collection_ids && NEW.collection_ids
168+
OR
169+
q.collection_ids IS NULL
170+
OR
171+
NEW.collection_ids IS NULL
172+
)
173+
) THEN
174+
RAISE unique_violation USING MESSAGE = format(
175+
'There is already a queryable for %s for a collection in %s: %s',
176+
NEW.name,
177+
NEW.collection_ids,
178+
(SELECT json_agg(row_to_json(q)) FROM queryables q WHERE
179+
q.name = NEW.name
180+
AND (
181+
q.collection_ids && NEW.collection_ids
182+
OR
183+
q.collection_ids IS NULL
184+
OR
185+
NEW.collection_ids IS NULL
186+
))
187+
);
188+
RETURN NULL;
189+
END IF;
190+
END IF;
191+
IF TG_OP = 'UPDATE' THEN
192+
IF EXISTS (
193+
SELECT 1 FROM queryables q
194+
WHERE
195+
q.id != NEW.id
196+
AND
197+
q.name = NEW.name
198+
AND (
199+
q.collection_ids && NEW.collection_ids
200+
OR
201+
q.collection_ids IS NULL
202+
OR
203+
NEW.collection_ids IS NULL
204+
)
205+
) THEN
206+
RAISE unique_violation
207+
USING MESSAGE = format(
208+
'There is already a queryable for %s for a collection in %s',
209+
NEW.name,
210+
NEW.collection_ids
211+
);
212+
RETURN NULL;
213+
END IF;
214+
END IF;
215+
216+
RETURN NEW;
217+
END;
218+
$function$
219+
;
220+
221+
222+
223+
-- END migra calculated SQL
224+
DO $$
225+
BEGIN
226+
INSERT INTO queryables (name, definition, property_wrapper, property_index_type) VALUES
227+
('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);
228+
EXCEPTION WHEN unique_violation THEN
229+
RAISE NOTICE '%', SQLERRM USING ERRCODE = SQLSTATE;
230+
END
231+
$$;
232+
233+
DO $$
234+
BEGIN
235+
INSERT INTO queryables (name, definition, property_wrapper, property_index_type) VALUES
236+
('geometry', '{"title": "Item Geometry","description": "Item Geometry","$ref": "https://geojson.org/schema/Feature.json"}', null, null);
237+
EXCEPTION WHEN unique_violation THEN
238+
RAISE NOTICE '%', SQLERRM USING ERRCODE = SQLSTATE;
239+
END
240+
$$;
241+
242+
DO $$
243+
BEGIN
244+
INSERT INTO queryables (name, definition, property_wrapper, property_index_type) VALUES
245+
('datetime','{"description": "Datetime","type": "string","title": "Acquired","format": "date-time","pattern": "(\\+00:00|Z)$"}', null, null);
246+
EXCEPTION WHEN unique_violation THEN
247+
RAISE NOTICE '%', SQLERRM USING ERRCODE = SQLSTATE;
248+
END
249+
$$;
250+
251+
DO $$
252+
BEGIN
253+
INSERT INTO queryables (name, definition, property_wrapper, property_index_type) VALUES
254+
('eo:cloud_cover','{"$ref": "https://stac-extensions.github.io/eo/v1.0.0/schema.json#/definitions/fieldsproperties/eo:cloud_cover"}','to_int','BTREE');
255+
EXCEPTION WHEN unique_violation THEN
256+
RAISE NOTICE '%', SQLERRM USING ERRCODE = SQLSTATE;
257+
END
258+
$$;
259+
260+
DELETE FROM queryables a USING queryables b
261+
WHERE a.name = b.name AND a.collection_ids IS NOT DISTINCT FROM b.collection_ids AND a.id > b.id;
262+
263+
264+
INSERT INTO pgstac_settings (name, value) VALUES
265+
('context', 'off'),
266+
('context_estimated_count', '100000'),
267+
('context_estimated_cost', '100000'),
268+
('context_stats_ttl', '1 day'),
269+
('default_filter_lang', 'cql2-json'),
270+
('additional_properties', 'true'),
271+
('use_queue', 'false'),
272+
('queue_timeout', '10 minutes'),
273+
('update_collection_extent', 'false'),
274+
('format_cache', 'false')
275+
ON CONFLICT DO NOTHING
276+
;
277+
278+
ALTER FUNCTION to_text COST 5000;
279+
ALTER FUNCTION to_float COST 5000;
280+
ALTER FUNCTION to_int COST 5000;
281+
ALTER FUNCTION to_tstz COST 5000;
282+
ALTER FUNCTION to_text_array COST 5000;
283+
284+
285+
GRANT USAGE ON SCHEMA pgstac to pgstac_read;
286+
GRANT ALL ON SCHEMA pgstac to pgstac_ingest;
287+
GRANT ALL ON SCHEMA pgstac to pgstac_admin;
288+
289+
-- pgstac_read role limited to using function apis
290+
GRANT EXECUTE ON FUNCTION search TO pgstac_read;
291+
GRANT EXECUTE ON FUNCTION search_query TO pgstac_read;
292+
GRANT EXECUTE ON FUNCTION item_by_id TO pgstac_read;
293+
GRANT EXECUTE ON FUNCTION get_item TO pgstac_read;
294+
GRANT SELECT ON ALL TABLES IN SCHEMA pgstac TO pgstac_read;
295+
296+
297+
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA pgstac to pgstac_ingest;
298+
GRANT ALL ON ALL TABLES IN SCHEMA pgstac to pgstac_ingest;
299+
GRANT USAGE ON ALL SEQUENCES IN SCHEMA pgstac to pgstac_ingest;
300+
301+
SELECT update_partition_stats_q(partition) FROM partitions;
302+
SELECT set_version('0.7.6');

0 commit comments

Comments
 (0)