Skip to content

Commit

Permalink
Add Search for Collections (#220)
Browse files Browse the repository at this point in the history
* initial collection_search function

* split collection search into 3 functions

* merge main

* add paging links

* start adding tests

* add collection search tests

* add items to changelog
  • Loading branch information
bitner authored Nov 7, 2023
1 parent 05c1caa commit 10ad866
Show file tree
Hide file tree
Showing 10 changed files with 679 additions and 15 deletions.
3 changes: 3 additions & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,9 @@ The format is based on [Keep a Changelog](http://keepachangelog.com/)
and this project adheres to [Semantic Versioning](http://semver.org/).

## [unreleased]
- Add support functions and tests for Collection Search
- Add configuration parameter for base_url to be able to generate absolute links
- With this release, this is only used to create links for paging in collection_search
- Adds read only mode to allow use of pgstac on read replicas
- Note: Turning on romode disables any caching (particularly when context is turned on) and does not allow to store q query hash that can be used with geometry_search.

Expand Down
35 changes: 24 additions & 11 deletions docker/pypgstac/bin/test
Original file line number Diff line number Diff line change
Expand Up @@ -102,20 +102,25 @@ ALTER DATABASE pgstac_test_basicsql SET pgstac."default_filter_lang" TO 'cql-jso
EOSQL

for SQLFILE in tests/basic/*.sql; do
TMPFILE=$(mktemp)
trap 'rm "$TMPFILE"' 0 2 3 15
SQLOUTFILE=${SQLFILE}.out
if [[ $CREATEBASICSQLOUT == 1 && ! -f $SQLOUTFILE ]]; then
TMPFILE=$SQLOUTFILE
else
TMPFILE=$(mktemp)
trap 'rm "$TMPFILE"' 0 2 3 15
fi

SQLOUTFILE=${SQLFILE}.out
cd $PGSTACDIR

echo "Running basic tests for $SQLFILE"
psql -X -t -a -v ON_ERROR_STOP=1 pgstac_test_basicsql \
-c "BEGIN;" \
-f $SQLFILE \
-c "ROLLBACK;" \
| sed -e '/^ROLLBACK/d' -e '/^BEGIN/d' >"$TMPFILE"
cd $PGSTACDIR

diff -Z -b -w -B --strip-trailing-cr --suppress-blank-empty -C 1 "$TMPFILE" $SQLOUTFILE && echo "TEST $SQLFILE PASSED" || { echo "***TEST FOR $SQLFILE FAILED***"; exit 1; }
echo "Running basic tests for $SQLFILE"
psql -X -t -a -v ON_ERROR_STOP=1 pgstac_test_basicsql \
-c "BEGIN;" \
-f $SQLFILE \
-c "ROLLBACK;" \
| sed -e '/^ROLLBACK/d' -e '/^BEGIN/d' >"$TMPFILE"

diff -Z -b -w -B --strip-trailing-cr --suppress-blank-empty -C 1 "$TMPFILE" $SQLOUTFILE && echo "TEST $SQLFILE PASSED" || { echo "***TEST FOR $SQLFILE FAILED***"; exit 1; }

done
psql -X -q -c "DROP DATABASE IF EXISTS pgstac_test_basicsql WITH (force);";
Expand Down Expand Up @@ -174,6 +179,7 @@ PYPGSTAC=0
MIGRATIONS=0
MESSAGENOTICE=0
MESSAGELOG=0
CREATEBASICSQLOUT=0

while [[ $# -gt 0 ]]
do
Expand Down Expand Up @@ -213,6 +219,13 @@ while [[ $# -gt 0 ]]
shift
;;

--basicsql-createout)
SETUPDB=1
BASICSQL=1
export CREATEBASICSQLOUT=1
shift
;;

--pypgstac)
SETUPDB=1
PYPGSTAC=1
Expand Down
160 changes: 160 additions & 0 deletions src/pgstac/migrations/pgstac.0.8.1-unreleased.sql
Original file line number Diff line number Diff line change
Expand Up @@ -186,6 +186,166 @@ AS $function$
$function$
;

CREATE OR REPLACE FUNCTION pgstac.base_url(conf jsonb DEFAULT NULL::jsonb)
RETURNS text
LANGUAGE sql
AS $function$
SELECT COALESCE(pgstac.get_setting('base_url', conf), '.');
$function$
;

CREATE OR REPLACE FUNCTION pgstac.collection_search(_search jsonb DEFAULT '{}'::jsonb)
RETURNS jsonb
LANGUAGE plpgsql
STABLE PARALLEL SAFE
AS $function$
DECLARE
out_records jsonb;
number_matched bigint := collection_search_matched(_search);
number_returned bigint;
_limit int := coalesce((_search->>'limit')::float::int, 10);
_offset int := coalesce((_search->>'offset')::float::int, 0);
links jsonb := '[]';
ret jsonb;
base_url text:= concat(rtrim(base_url(_search->'conf'),'/'), '/collections');
prevoffset int;
nextoffset int;
BEGIN
SELECT
coalesce(jsonb_agg(c), '[]')
INTO out_records
FROM collection_search_rows(_search) c;

number_returned := jsonb_array_length(out_records);

IF _limit <= number_matched THEN --need to have paging links
nextoffset := least(_offset + _limit, number_matched - 1);
prevoffset := greatest(_offset - _limit, 0);
IF _offset = 0 THEN -- no previous paging

links := jsonb_build_array(
jsonb_build_object(
'rel', 'next',
'type', 'application/json',
'method', 'GET' ,
'href', base_url,
'body', jsonb_build_object('offset', nextoffset),
'merge', TRUE
)
);
ELSE
links := jsonb_build_array(
jsonb_build_object(
'rel', 'prev',
'type', 'application/json',
'method', 'GET' ,
'href', base_url,
'body', jsonb_build_object('offset', prevoffset),
'merge', TRUE
),
jsonb_build_object(
'rel', 'next',
'type', 'application/json',
'method', 'GET' ,
'href', base_url,
'body', jsonb_build_object('offset', nextoffset),
'merge', TRUE
)
);
END IF;
END IF;

ret := jsonb_build_object(
'collections', out_records,
'context', jsonb_build_object(
'limit', _limit,
'matched', number_matched,
'returned', number_returned
),
'links', links
);
RETURN ret;

END;
$function$
;

CREATE OR REPLACE FUNCTION pgstac.collection_search_matched(_search jsonb DEFAULT '{}'::jsonb, OUT matched bigint)
RETURNS bigint
LANGUAGE plpgsql
STABLE PARALLEL SAFE
AS $function$
DECLARE
_where text := stac_search_to_where(_search);
BEGIN
EXECUTE format(
$query$
SELECT
count(*)
FROM
collections_asitems
WHERE %s
;
$query$,
_where
) INTO matched;
RETURN;
END;
$function$
;

CREATE OR REPLACE FUNCTION pgstac.collection_search_rows(_search jsonb DEFAULT '{}'::jsonb)
RETURNS SETOF jsonb
LANGUAGE plpgsql
AS $function$
DECLARE
_where text := stac_search_to_where(_search);
_limit int := coalesce((_search->>'limit')::int, 10);
_fields jsonb := coalesce(_search->'fields', '{}'::jsonb);
_orderby text;
_offset int := COALESCE((_search->>'offset')::int, 0);
BEGIN
_orderby := sort_sqlorderby(
jsonb_build_object(
'sortby',
coalesce(
_search->'sortby',
'[{"field": "id", "direction": "asc"}]'::jsonb
)
)
);
RETURN QUERY EXECUTE format(
$query$
SELECT
jsonb_fields(collectionjson, %L) as c
FROM
collections_asitems
WHERE %s
ORDER BY %s
LIMIT %L
OFFSET %L
;
$query$,
_fields,
_where,
_orderby,
_limit,
_offset
);
END;
$function$
;

create or replace view "pgstac"."collections_asitems" as SELECT collections.id,
collections.geometry,
'collections'::text AS collection,
collections.datetime,
collections.end_datetime,
jsonb_build_object('properties', (collections.content - '{links,assets,stac_version,stac_extensions}'::text), 'links', (collections.content -> 'links'::text), 'assets', (collections.content -> 'assets'::text), 'stac_version', (collections.content -> 'stac_version'::text), 'stac_extensions', (collections.content -> 'stac_extensions'::text)) AS content,
collections.content AS collectionjson
FROM collections;


CREATE OR REPLACE FUNCTION pgstac.readonly(conf jsonb DEFAULT NULL::jsonb)
RETURNS boolean
LANGUAGE sql
Expand Down
Loading

0 comments on commit 10ad866

Please sign in to comment.