Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Read only configuration mode #215

Merged
merged 4 commits into from
Nov 6, 2023
Merged
Show file tree
Hide file tree
Changes from 3 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
204 changes: 203 additions & 1 deletion src/pgstac/migrations/pgstac.0.8.1-unreleased.sql
Original file line number Diff line number Diff line change
Expand Up @@ -186,6 +186,14 @@ AS $function$
$function$
;

CREATE OR REPLACE FUNCTION pgstac.readonly(conf jsonb DEFAULT NULL::jsonb)
RETURNS boolean
LANGUAGE sql
AS $function$
SELECT pgstac.get_setting_bool('readonly', conf);
$function$
;

CREATE OR REPLACE FUNCTION pgstac.cql2_query(j jsonb, wrapper text DEFAULT NULL::text)
RETURNS text
LANGUAGE plpgsql
Expand Down Expand Up @@ -434,6 +442,199 @@ END;
$function$
;

CREATE OR REPLACE FUNCTION pgstac.search_query(_search jsonb DEFAULT '{}'::jsonb, updatestats boolean DEFAULT false, _metadata jsonb DEFAULT '{}'::jsonb)
RETURNS searches
LANGUAGE plpgsql
SECURITY DEFINER
AS $function$
DECLARE
search searches%ROWTYPE;
pexplain jsonb;
t timestamptz;
i interval;
_hash text := search_hash(_search, _metadata);
doupdate boolean := FALSE;
insertfound boolean := FALSE;
ro boolean := pgstac.readonly();
BEGIN
IF ro THEN
updatestats := FALSE;
END IF;

SELECT * INTO search FROM searches
WHERE hash=_hash;

search.hash := _hash;

-- Calculate the where clause if not already calculated
IF search._where IS NULL THEN
search._where := stac_search_to_where(_search);
ELSE
doupdate := TRUE;
END IF;

-- Calculate the order by clause if not already calculated
IF search.orderby IS NULL THEN
search.orderby := sort_sqlorderby(_search);
ELSE
doupdate := TRUE;
END IF;

PERFORM where_stats(search._where, updatestats, _search->'conf');

IF NOT ro THEN
IF NOT doupdate THEN
INSERT INTO searches (search, _where, orderby, lastused, usecount, metadata)
VALUES (_search, search._where, search.orderby, clock_timestamp(), 1, _metadata)
ON CONFLICT (hash) DO NOTHING RETURNING * INTO search;
IF FOUND THEN
RETURN search;
END IF;
END IF;

UPDATE searches
SET
lastused=clock_timestamp(),
usecount=usecount+1
WHERE hash=(
SELECT hash FROM searches
WHERE hash=_hash
FOR UPDATE SKIP LOCKED
);
IF NOT FOUND THEN
RAISE NOTICE 'Did not update stats for % due to lock. (This is generally OK)', _search;
END IF;
END IF;

RETURN search;

END;
$function$
;

CREATE OR REPLACE FUNCTION pgstac.where_stats(inwhere text, updatestats boolean DEFAULT false, conf jsonb DEFAULT NULL::jsonb)
RETURNS search_wheres
LANGUAGE plpgsql
SECURITY DEFINER
AS $function$
DECLARE
t timestamptz;
i interval;
explain_json jsonb;
partitions text[];
sw search_wheres%ROWTYPE;
inwhere_hash text := md5(inwhere);
_context text := lower(context(conf));
_stats_ttl interval := context_stats_ttl(conf);
_estimated_cost float := context_estimated_cost(conf);
_estimated_count int := context_estimated_count(conf);
ro bool := pgstac.readonly(conf);
BEGIN
IF ro THEN
updatestats := FALSE;
END IF;

IF _context = 'off' THEN
sw._where := inwhere;
return sw;
END IF;

SELECT * INTO sw FROM search_wheres WHERE md5(_where)=inwhere_hash FOR UPDATE;

-- Update statistics if explicitly set, if statistics do not exist, or statistics ttl has expired
IF NOT updatestats THEN
RAISE NOTICE 'Checking if update is needed for: % .', inwhere;
RAISE NOTICE 'Stats Last Updated: %', sw.statslastupdated;
RAISE NOTICE 'TTL: %, Age: %', _stats_ttl, now() - sw.statslastupdated;
RAISE NOTICE 'Context: %, Existing Total: %', _context, sw.total_count;
IF
(
sw.statslastupdated IS NULL
OR (now() - sw.statslastupdated) > _stats_ttl
OR (context(conf) != 'off' AND sw.total_count IS NULL)
) AND NOT ro
THEN
updatestats := TRUE;
END IF;
END IF;

sw._where := inwhere;
sw.lastused := now();
sw.usecount := coalesce(sw.usecount,0) + 1;

IF NOT updatestats THEN
UPDATE search_wheres SET
lastused = sw.lastused,
usecount = sw.usecount
WHERE md5(_where) = inwhere_hash
RETURNING * INTO sw
;
RETURN sw;
END IF;

-- Use explain to get estimated count/cost and a list of the partitions that would be hit by the query
t := clock_timestamp();
EXECUTE format('EXPLAIN (format json) SELECT 1 FROM items WHERE %s', inwhere)
INTO explain_json;
RAISE NOTICE 'Time for just the explain: %', clock_timestamp() - t;
i := clock_timestamp() - t;

sw.statslastupdated := now();
sw.estimated_count := explain_json->0->'Plan'->'Plan Rows';
sw.estimated_cost := explain_json->0->'Plan'->'Total Cost';
sw.time_to_estimate := extract(epoch from i);

RAISE NOTICE 'ESTIMATED_COUNT: % < %', sw.estimated_count, _estimated_count;
RAISE NOTICE 'ESTIMATED_COST: % < %', sw.estimated_cost, _estimated_cost;

-- Do a full count of rows if context is set to on or if auto is set and estimates are low enough
IF
_context = 'on'
OR
( _context = 'auto' AND
(
sw.estimated_count < _estimated_count
AND
sw.estimated_cost < _estimated_cost
)
)
THEN
t := clock_timestamp();
RAISE NOTICE 'Calculating actual count...';
EXECUTE format(
'SELECT count(*) FROM items WHERE %s',
inwhere
) INTO sw.total_count;
i := clock_timestamp() - t;
RAISE NOTICE 'Actual Count: % -- %', sw.total_count, i;
sw.time_to_count := extract(epoch FROM i);
ELSE
sw.total_count := NULL;
sw.time_to_count := NULL;
END IF;

IF NOT ro THEN
INSERT INTO search_wheres
(_where, lastused, usecount, statslastupdated, estimated_count, estimated_cost, time_to_estimate, partitions, total_count, time_to_count)
SELECT sw._where, sw.lastused, sw.usecount, sw.statslastupdated, sw.estimated_count, sw.estimated_cost, sw.time_to_estimate, sw.partitions, sw.total_count, sw.time_to_count
ON CONFLICT ((md5(_where)))
DO UPDATE
SET
lastused = sw.lastused,
usecount = sw.usecount,
statslastupdated = sw.statslastupdated,
estimated_count = sw.estimated_count,
estimated_cost = sw.estimated_cost,
time_to_estimate = sw.time_to_estimate,
total_count = sw.total_count,
time_to_count = sw.time_to_count
;
END IF;
RETURN sw;
END;
$function$
;


-- END migra calculated SQL
DO $$
Expand Down Expand Up @@ -477,7 +678,8 @@ INSERT INTO pgstac_settings (name, value) VALUES
('use_queue', 'false'),
('queue_timeout', '10 minutes'),
('update_collection_extent', 'false'),
('format_cache', 'false')
('format_cache', 'false'),
('readonly', 'false')
ON CONFLICT DO NOTHING
;

Expand Down
96 changes: 58 additions & 38 deletions src/pgstac/migrations/pgstac.unreleased.sql
Original file line number Diff line number Diff line change
Expand Up @@ -230,6 +230,10 @@ CREATE OR REPLACE FUNCTION additional_properties() RETURNS boolean AS $$
SELECT pgstac.get_setting_bool('additional_properties');
$$ LANGUAGE SQL;

CREATE OR REPLACE FUNCTION readonly(conf jsonb DEFAULT NULL) RETURNS boolean AS $$
SELECT pgstac.get_setting_bool('readonly', conf);
$$ LANGUAGE SQL;

CREATE OR REPLACE FUNCTION context(conf jsonb DEFAULT NULL) RETURNS text AS $$
SELECT pgstac.get_setting('context', conf);
$$ LANGUAGE SQL;
Expand Down Expand Up @@ -3284,7 +3288,12 @@ DECLARE
_stats_ttl interval := context_stats_ttl(conf);
_estimated_cost float := context_estimated_cost(conf);
_estimated_count int := context_estimated_count(conf);
ro bool := pgstac.readonly(conf);
BEGIN
IF ro THEN
updatestats := FALSE;
END IF;

IF _context = 'off' THEN
sw._where := inwhere;
return sw;
Expand All @@ -3299,9 +3308,11 @@ BEGIN
RAISE NOTICE 'TTL: %, Age: %', _stats_ttl, now() - sw.statslastupdated;
RAISE NOTICE 'Context: %, Existing Total: %', _context, sw.total_count;
IF
sw.statslastupdated IS NULL
OR (now() - sw.statslastupdated) > _stats_ttl
OR (context(conf) != 'off' AND sw.total_count IS NULL)
(
sw.statslastupdated IS NULL
OR (now() - sw.statslastupdated) > _stats_ttl
OR (context(conf) != 'off' AND sw.total_count IS NULL)
) AND NOT ro
THEN
updatestats := TRUE;
END IF;
Expand Down Expand Up @@ -3362,22 +3373,23 @@ BEGIN
sw.time_to_count := NULL;
END IF;


INSERT INTO search_wheres
(_where, lastused, usecount, statslastupdated, estimated_count, estimated_cost, time_to_estimate, partitions, total_count, time_to_count)
SELECT sw._where, sw.lastused, sw.usecount, sw.statslastupdated, sw.estimated_count, sw.estimated_cost, sw.time_to_estimate, sw.partitions, sw.total_count, sw.time_to_count
ON CONFLICT ((md5(_where)))
DO UPDATE
SET
lastused = sw.lastused,
usecount = sw.usecount,
statslastupdated = sw.statslastupdated,
estimated_count = sw.estimated_count,
estimated_cost = sw.estimated_cost,
time_to_estimate = sw.time_to_estimate,
total_count = sw.total_count,
time_to_count = sw.time_to_count
;
IF NOT ro THEN
INSERT INTO search_wheres
(_where, lastused, usecount, statslastupdated, estimated_count, estimated_cost, time_to_estimate, partitions, total_count, time_to_count)
SELECT sw._where, sw.lastused, sw.usecount, sw.statslastupdated, sw.estimated_count, sw.estimated_cost, sw.time_to_estimate, sw.partitions, sw.total_count, sw.time_to_count
ON CONFLICT ((md5(_where)))
DO UPDATE
SET
lastused = sw.lastused,
usecount = sw.usecount,
statslastupdated = sw.statslastupdated,
estimated_count = sw.estimated_count,
estimated_cost = sw.estimated_cost,
time_to_estimate = sw.time_to_estimate,
total_count = sw.total_count,
time_to_count = sw.time_to_count
;
END IF;
RETURN sw;
END;
$$ LANGUAGE PLPGSQL SECURITY DEFINER;
Expand All @@ -3396,7 +3408,12 @@ DECLARE
_hash text := search_hash(_search, _metadata);
doupdate boolean := FALSE;
insertfound boolean := FALSE;
ro boolean := pgstac.readonly();
BEGIN
IF ro THEN
updatestats := FALSE;
END IF;

SELECT * INTO search FROM searches
WHERE hash=_hash;

Expand All @@ -3418,26 +3435,28 @@ BEGIN

PERFORM where_stats(search._where, updatestats, _search->'conf');

IF NOT doupdate THEN
INSERT INTO searches (search, _where, orderby, lastused, usecount, metadata)
VALUES (_search, search._where, search.orderby, clock_timestamp(), 1, _metadata)
ON CONFLICT (hash) DO NOTHING RETURNING * INTO search;
IF FOUND THEN
RETURN search;
IF NOT ro THEN
IF NOT doupdate THEN
INSERT INTO searches (search, _where, orderby, lastused, usecount, metadata)
VALUES (_search, search._where, search.orderby, clock_timestamp(), 1, _metadata)
ON CONFLICT (hash) DO NOTHING RETURNING * INTO search;
IF FOUND THEN
RETURN search;
END IF;
END IF;
END IF;

UPDATE searches
SET
lastused=clock_timestamp(),
usecount=usecount+1
WHERE hash=(
SELECT hash FROM searches
WHERE hash=_hash
FOR UPDATE SKIP LOCKED
);
IF NOT FOUND THEN
RAISE NOTICE 'Did not update stats for % due to lock. (This is generally OK)', _search;
UPDATE searches
SET
lastused=clock_timestamp(),
usecount=usecount+1
WHERE hash=(
SELECT hash FROM searches
WHERE hash=_hash
FOR UPDATE SKIP LOCKED
);
IF NOT FOUND THEN
RAISE NOTICE 'Did not update stats for % due to lock. (This is generally OK)', _search;
END IF;
END IF;

RETURN search;
Expand Down Expand Up @@ -4084,7 +4103,8 @@ INSERT INTO pgstac_settings (name, value) VALUES
('use_queue', 'false'),
('queue_timeout', '10 minutes'),
('update_collection_extent', 'false'),
('format_cache', 'false')
('format_cache', 'false'),
('readonly', 'false')
ON CONFLICT DO NOTHING
;

Expand Down
4 changes: 4 additions & 0 deletions src/pgstac/sql/001_core.sql
Original file line number Diff line number Diff line change
Expand Up @@ -55,6 +55,10 @@ CREATE OR REPLACE FUNCTION additional_properties() RETURNS boolean AS $$
SELECT pgstac.get_setting_bool('additional_properties');
$$ LANGUAGE SQL;

CREATE OR REPLACE FUNCTION readonly(conf jsonb DEFAULT NULL) RETURNS boolean AS $$
SELECT pgstac.get_setting_bool('readonly', conf);
$$ LANGUAGE SQL;

CREATE OR REPLACE FUNCTION context(conf jsonb DEFAULT NULL) RETURNS text AS $$
SELECT pgstac.get_setting('context', conf);
$$ LANGUAGE SQL;
Expand Down
Loading