Skip to content

Commit 78d3ecd

Browse files
authored
Work v0.4.1 (#78)
* add changelog, fix filter-lang * fix for long queries in cache * stage version
1 parent 3afa5df commit 78d3ecd

File tree

7 files changed

+2642
-12
lines changed

7 files changed

+2642
-12
lines changed

CHANGELOG.md

Lines changed: 22 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -1,11 +1,30 @@
11
# Changelog
22

3-
## Ureleased
3+
## [v0.4.1]
44

5-
## Changed
5+
### Changed
66

77
- Update `typer` to 0.4.0 to avoid clashes with `click` ([#76](https://github.com/stac-utils/pgstac/pull/76))
88

9+
### Fixed
10+
11+
- Fix logic in getting settings to make sure that filter-lang set on query is respected. ([#77](https://github.com/stac-utils/pgstac/pull/77))
12+
- Fix for large queries in the query cache. ([#71](https://github.com/stac-utils/pgstac/pull/71))
13+
14+
15+
## [v0.4.0]
16+
17+
### Fixed
18+
- Fixes syntax for IN, BETWEEN, ISNULL, and NOT in CQL 1 ([#69](https://github.com/stac-utils/pgstac/pull/69))
19+
20+
### Added
21+
- Adds support for modifying settings through pgstac_settings table and by passing in 'conf' object in search json to support AWS RDS where custom user configuration settings are not allowed and changing settings on the fly for a given query.
22+
- Adds support for CQL2-JSON ([#67](https://github.com/stac-utils/pgstac/pull/67))
23+
- Adds tests for all examples in https://github.com/radiantearth/stac-api-spec/blob/f5da775080ff3ff46d454c2888b6e796ee956faf/fragments/filter/README.md
24+
- filter-lang parameter controls which dialect of CQL to use
25+
- Adds 'default-filter-lang' setting to control what dialect to use when 'filter-lang' is not present
26+
- old style stac 'query' object and top level ids, collections, datetime, bbox, and intersects parameters are only available with cql-json
27+
928
## [v0.3.4]
1029

1130
### Added
@@ -15,7 +34,7 @@
1534

1635
## [v0.3.3]
1736

18-
## Fixed
37+
### Fixed
1938

2039
- Fixed CQL term to be "id", not "ids" ([#46](https://github.com/stac-utils/pgstac/pull/46))
2140
- Make sure featureCollection response has empty features `[]` not `null` ([#46](https://github.com/stac-utils/pgstac/pull/46))

pypgstac/pypgstac/__init__.py

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,2 +1,2 @@
11
"""PyPGStac Version."""
2-
__version__ = "0.4.0"
2+
__version__ = "0.4.1"
Lines changed: 169 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,169 @@
1+
SET SEARCH_PATH to pgstac, public;
2+
alter table "pgstac"."search_wheres" drop constraint "search_wheres_pkey";
3+
4+
drop index if exists "pgstac"."search_wheres_pkey";
5+
6+
alter table "pgstac"."search_wheres" add column "id" bigint generated always as identity not null;
7+
8+
CREATE UNIQUE INDEX search_wheres_where ON pgstac.search_wheres USING btree (md5(_where));
9+
10+
CREATE UNIQUE INDEX search_wheres_pkey ON pgstac.search_wheres USING btree (id);
11+
12+
alter table "pgstac"."search_wheres" add constraint "search_wheres_pkey" PRIMARY KEY using index "search_wheres_pkey";
13+
14+
set check_function_bodies = off;
15+
16+
CREATE OR REPLACE FUNCTION pgstac.cql_to_where(_search jsonb DEFAULT '{}'::jsonb)
17+
RETURNS text
18+
LANGUAGE plpgsql
19+
AS $function$
20+
DECLARE
21+
filterlang text;
22+
search jsonb := _search;
23+
_where text;
24+
BEGIN
25+
26+
RAISE NOTICE 'SEARCH CQL Final: %', search;
27+
filterlang := COALESCE(
28+
search->>'filter-lang',
29+
get_setting('default-filter-lang', _search->'conf')
30+
);
31+
32+
IF filterlang = 'cql-json' THEN
33+
search := query_to_cqlfilter(search);
34+
search := add_filters_to_cql(search);
35+
_where := cql_query_op(search->'filter');
36+
ELSE
37+
_where := cql2_query(search->'filter');
38+
END IF;
39+
40+
IF trim(_where) = '' THEN
41+
_where := NULL;
42+
END IF;
43+
_where := coalesce(_where, ' TRUE ');
44+
RETURN _where;
45+
END;
46+
$function$
47+
;
48+
49+
CREATE OR REPLACE FUNCTION pgstac.where_stats(inwhere text, updatestats boolean DEFAULT false, conf jsonb DEFAULT NULL::jsonb)
50+
RETURNS search_wheres
51+
LANGUAGE plpgsql
52+
AS $function$
53+
DECLARE
54+
t timestamptz;
55+
i interval;
56+
explain_json jsonb;
57+
partitions text[];
58+
sw search_wheres%ROWTYPE;
59+
BEGIN
60+
SELECT * INTO sw FROM search_wheres WHERE _where=inwhere FOR UPDATE;
61+
62+
-- Update statistics if explicitly set, if statistics do not exist, or statistics ttl has expired
63+
IF NOT updatestats THEN
64+
RAISE NOTICE 'Checking if update is needed.';
65+
RAISE NOTICE 'Stats Last Updated: %', sw.statslastupdated;
66+
RAISE NOTICE 'TTL: %, Age: %', context_stats_ttl(conf), now() - sw.statslastupdated;
67+
RAISE NOTICE 'Context: %, Existing Total: %', context(conf), sw.total_count;
68+
IF
69+
sw.statslastupdated IS NULL
70+
OR (now() - sw.statslastupdated) > context_stats_ttl(conf)
71+
OR (context(conf) != 'off' AND sw.total_count IS NULL)
72+
THEN
73+
updatestats := TRUE;
74+
END IF;
75+
END IF;
76+
77+
sw._where := inwhere;
78+
sw.lastused := now();
79+
sw.usecount := coalesce(sw.usecount,0) + 1;
80+
81+
IF NOT updatestats THEN
82+
UPDATE search_wheres SET
83+
lastused = sw.lastused,
84+
usecount = sw.usecount
85+
WHERE _where = inwhere
86+
RETURNING * INTO sw
87+
;
88+
RETURN sw;
89+
END IF;
90+
-- Use explain to get estimated count/cost and a list of the partitions that would be hit by the query
91+
t := clock_timestamp();
92+
EXECUTE format('EXPLAIN (format json) SELECT 1 FROM items WHERE %s', inwhere)
93+
INTO explain_json;
94+
RAISE NOTICE 'Time for just the explain: %', clock_timestamp() - t;
95+
WITH t AS (
96+
SELECT j->>0 as p FROM
97+
jsonb_path_query(
98+
explain_json,
99+
'strict $.**."Relation Name" ? (@ != null)'
100+
) j
101+
), ordered AS (
102+
SELECT p FROM t ORDER BY p DESC
103+
-- SELECT p FROM t JOIN items_partitions
104+
-- ON (t.p = items_partitions.partition)
105+
-- ORDER BY pstart DESC
106+
)
107+
SELECT array_agg(p) INTO partitions FROM ordered;
108+
i := clock_timestamp() - t;
109+
RAISE NOTICE 'Time for explain + join: %', clock_timestamp() - t;
110+
111+
112+
113+
sw.statslastupdated := now();
114+
sw.estimated_count := explain_json->0->'Plan'->'Plan Rows';
115+
sw.estimated_cost := explain_json->0->'Plan'->'Total Cost';
116+
sw.time_to_estimate := extract(epoch from i);
117+
sw.partitions := partitions;
118+
119+
-- Do a full count of rows if context is set to on or if auto is set and estimates are low enough
120+
IF
121+
context(conf) = 'on'
122+
OR
123+
( context(conf) = 'auto' AND
124+
(
125+
sw.estimated_count < context_estimated_count(conf)
126+
OR
127+
sw.estimated_cost < context_estimated_cost(conf)
128+
)
129+
)
130+
THEN
131+
t := clock_timestamp();
132+
RAISE NOTICE 'Calculating actual count...';
133+
EXECUTE format(
134+
'SELECT count(*) FROM items WHERE %s',
135+
inwhere
136+
) INTO sw.total_count;
137+
i := clock_timestamp() - t;
138+
RAISE NOTICE 'Actual Count: % -- %', sw.total_count, i;
139+
sw.time_to_count := extract(epoch FROM i);
140+
ELSE
141+
sw.total_count := NULL;
142+
sw.time_to_count := NULL;
143+
END IF;
144+
145+
146+
INSERT INTO search_wheres
147+
(_where, lastused, usecount, statslastupdated, estimated_count, estimated_cost, time_to_estimate, partitions, total_count, time_to_count)
148+
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
149+
ON CONFLICT ((md5(_where)))
150+
DO UPDATE
151+
SET
152+
lastused = sw.lastused,
153+
usecount = sw.usecount,
154+
statslastupdated = sw.statslastupdated,
155+
estimated_count = sw.estimated_count,
156+
estimated_cost = sw.estimated_cost,
157+
time_to_estimate = sw.time_to_estimate,
158+
partitions = sw.partitions,
159+
total_count = sw.total_count,
160+
time_to_count = sw.time_to_count
161+
;
162+
RETURN sw;
163+
END;
164+
$function$
165+
;
166+
167+
168+
169+
SELECT set_version('0.4.1');

0 commit comments

Comments
 (0)