From 27385310b3945f02f963b411ccd7725d4052aedd Mon Sep 17 00:00:00 2001
From: David Bitner <bitner@dbspatial.com>
Date: Tue, 27 Jul 2021 11:49:22 -0500
Subject: [PATCH 01/10] bump version to 0.2.9

---
 pypgstac/pypgstac/__init__.py                 |    2 +-
 .../migrations/pgstac.0.2.8-0.2.9.sql         |    2 +
 pypgstac/pypgstac/migrations/pgstac.0.2.9.sql | 1019 +++++++++++++++++
 pypgstac/pyproject.toml                       |    2 +-
 sql/999_version.sql                           |    2 +-
 5 files changed, 1024 insertions(+), 3 deletions(-)
 create mode 100644 pypgstac/pypgstac/migrations/pgstac.0.2.8-0.2.9.sql
 create mode 100644 pypgstac/pypgstac/migrations/pgstac.0.2.9.sql

diff --git a/pypgstac/pypgstac/__init__.py b/pypgstac/pypgstac/__init__.py
index d0e2432b..150f0035 100644
--- a/pypgstac/pypgstac/__init__.py
+++ b/pypgstac/pypgstac/__init__.py
@@ -1,2 +1,2 @@
 """PyPGStac Version."""
-__version__ = "0.2.8"
+__version__ = "0.2.9"
diff --git a/pypgstac/pypgstac/migrations/pgstac.0.2.8-0.2.9.sql b/pypgstac/pypgstac/migrations/pgstac.0.2.8-0.2.9.sql
new file mode 100644
index 00000000..f01befc5
--- /dev/null
+++ b/pypgstac/pypgstac/migrations/pgstac.0.2.8-0.2.9.sql
@@ -0,0 +1,2 @@
+SET SEARCH_PATH to pgstac, public;
+INSERT INTO migrations (version) VALUES ('0.2.9');
diff --git a/pypgstac/pypgstac/migrations/pgstac.0.2.9.sql b/pypgstac/pypgstac/migrations/pgstac.0.2.9.sql
new file mode 100644
index 00000000..a1aef24d
--- /dev/null
+++ b/pypgstac/pypgstac/migrations/pgstac.0.2.9.sql
@@ -0,0 +1,1019 @@
+CREATE EXTENSION IF NOT EXISTS postgis;
+CREATE SCHEMA IF NOT EXISTS partman;
+CREATE EXTENSION IF NOT EXISTS pg_partman SCHEMA partman;
+CREATE SCHEMA IF NOT EXISTS pgstac;
+
+
+SET SEARCH_PATH TO pgstac, public;
+
+CREATE TABLE migrations (
+  version text,
+  datetime timestamptz DEFAULT now() NOT NULL
+);
+
+/* converts a jsonb text array to a pg text[] array */
+CREATE OR REPLACE FUNCTION textarr(_js jsonb)
+  RETURNS text[] AS $$
+  SELECT ARRAY(SELECT jsonb_array_elements_text(_js));
+$$ LANGUAGE sql IMMUTABLE PARALLEL SAFE;
+
+/*
+converts a jsonb text array to comma delimited list of identifer quoted
+useful for constructing column lists for selects
+*/
+CREATE OR REPLACE FUNCTION array_idents(_js jsonb)
+  RETURNS text AS $$
+  SELECT string_agg(quote_ident(v),',') FROM jsonb_array_elements_text(_js) v;
+$$ LANGUAGE sql IMMUTABLE PARALLEL SAFE;
+
+
+/* looks for a geometry in a stac item first from geometry and falling back to bbox */
+CREATE OR REPLACE FUNCTION stac_geom(value jsonb) RETURNS geometry AS $$
+SELECT
+    CASE
+            WHEN value->>'geometry' IS NOT NULL THEN
+                ST_GeomFromGeoJSON(value->>'geometry')
+            WHEN value->>'bbox' IS NOT NULL THEN
+                ST_MakeEnvelope(
+                    (value->'bbox'->>0)::float,
+                    (value->'bbox'->>1)::float,
+                    (value->'bbox'->>2)::float,
+                    (value->'bbox'->>3)::float,
+                    4326
+                )
+            ELSE NULL
+        END as geometry
+;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION stac_datetime(value jsonb) RETURNS timestamptz AS $$
+SELECT (value->'properties'->>'datetime')::timestamptz;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE SET TIMEZONE='UTC';
+
+CREATE OR REPLACE FUNCTION jsonb_paths (IN jdata jsonb, OUT path text[], OUT value jsonb) RETURNS
+SETOF RECORD AS $$
+with recursive extract_all as
+(
+    select
+        ARRAY[key]::text[] as path,
+        value
+    FROM jsonb_each(jdata)
+union all
+    select
+        path || coalesce(obj_key, (arr_key- 1)::text),
+        coalesce(obj_value, arr_value)
+    from extract_all
+    left join lateral
+        jsonb_each(case jsonb_typeof(value) when 'object' then value end)
+        as o(obj_key, obj_value)
+        on jsonb_typeof(value) = 'object'
+    left join lateral
+        jsonb_array_elements(case jsonb_typeof(value) when 'array' then value end)
+        with ordinality as a(arr_value, arr_key)
+        on jsonb_typeof(value) = 'array'
+    where obj_key is not null or arr_key is not null
+)
+select *
+from extract_all;
+$$ LANGUAGE SQL;
+
+CREATE OR REPLACE FUNCTION jsonb_obj_paths (IN jdata jsonb, OUT path text[], OUT value jsonb) RETURNS
+SETOF RECORD AS $$
+with recursive extract_all as
+(
+    select
+        ARRAY[key]::text[] as path,
+        value
+    FROM jsonb_each(jdata)
+union all
+    select
+        path || obj_key,
+        obj_value
+    from extract_all
+    left join lateral
+        jsonb_each(case jsonb_typeof(value) when 'object' then value end)
+        as o(obj_key, obj_value)
+        on jsonb_typeof(value) = 'object'
+    where obj_key is not null
+)
+select *
+from extract_all;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION jsonb_val_paths (IN jdata jsonb, OUT path text[], OUT value jsonb) RETURNS
+SETOF RECORD AS $$
+SELECT * FROM jsonb_obj_paths(jdata) WHERE jsonb_typeof(value) not in  ('object','array');
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+
+CREATE OR REPLACE FUNCTION path_includes(IN path text[], IN includes text[]) RETURNS BOOLEAN AS $$
+WITH t AS (SELECT unnest(includes) i)
+SELECT EXISTS (
+    SELECT 1 FROM t WHERE path @> string_to_array(trim(i), '.')
+);
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION path_excludes(IN path text[], IN excludes text[]) RETURNS BOOLEAN AS $$
+WITH t AS (SELECT unnest(excludes) e)
+SELECT NOT EXISTS (
+    SELECT 1 FROM t WHERE path @> string_to_array(trim(e), '.')
+);
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+
+CREATE OR REPLACE FUNCTION jsonb_obj_paths_filtered (
+    IN jdata jsonb,
+    IN includes text[] DEFAULT ARRAY[]::text[],
+    IN excludes text[] DEFAULT ARRAY[]::text[],
+    OUT path text[],
+    OUT value jsonb
+) RETURNS
+SETOF RECORD AS $$
+SELECT path, value
+FROM jsonb_obj_paths(jdata)
+WHERE
+    CASE WHEN cardinality(includes) > 0 THEN path_includes(path, includes) ELSE TRUE END
+    AND
+    path_excludes(path, excludes)
+
+;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION empty_arr(ANYARRAY) RETURNS BOOLEAN AS $$
+SELECT CASE
+  WHEN $1 IS NULL THEN TRUE
+  WHEN cardinality($1)<1 THEN TRUE
+ELSE FALSE
+END;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+
+CREATE OR REPLACE FUNCTION filter_jsonb(
+    IN jdata jsonb,
+    IN includes text[] DEFAULT ARRAY[]::text[],
+    IN excludes text[] DEFAULT ARRAY[]::text[]
+) RETURNS jsonb AS $$
+DECLARE
+rec RECORD;
+outj jsonb := '{}'::jsonb;
+created_paths text[] := '{}'::text[];
+BEGIN
+
+IF empty_arr(includes) AND empty_arr(excludes) THEN
+RAISE NOTICE 'no filter';
+  RETURN jdata;
+END IF;
+FOR rec in
+SELECT * FROM jsonb_obj_paths_filtered(jdata, includes, excludes)
+WHERE jsonb_typeof(value) != 'object'
+LOOP
+    IF array_length(rec.path,1)>1 THEN
+        FOR i IN 1..(array_length(rec.path,1)-1) LOOP
+          IF NOT array_to_string(rec.path[1:i],'.') = ANY (created_paths) THEN
+            outj := jsonb_set(outj, rec.path[1:i],'{}', true);
+            created_paths := created_paths || array_to_string(rec.path[1:i],'.');
+          END IF;
+        END LOOP;
+    END IF;
+    outj := jsonb_set(outj, rec.path, rec.value, true);
+    created_paths := created_paths || array_to_string(rec.path,'.');
+END LOOP;
+RETURN outj;
+END;
+$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION properties_idx(_in jsonb) RETURNS jsonb AS $$
+WITH t AS (
+  select array_to_string(path,'.') as path, lower(value::text)::jsonb as lowerval
+  FROM  jsonb_val_paths(_in)
+  WHERE array_to_string(path,'.') not in ('datetime')
+)
+SELECT jsonb_object_agg(path, lowerval) FROM t;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+SET SEARCH_PATH TO pgstac, public;
+
+CREATE TABLE IF NOT EXISTS collections (
+    id VARCHAR GENERATED ALWAYS AS (content->>'id') STORED PRIMARY KEY,
+    content JSONB
+);
+
+CREATE OR REPLACE FUNCTION create_collection(data jsonb) RETURNS VOID AS $$
+    INSERT INTO collections (content)
+    VALUES (data)
+    ;
+$$ LANGUAGE SQL SET SEARCH_PATH TO pgstac, public;
+
+CREATE OR REPLACE FUNCTION update_collection(data jsonb) RETURNS VOID AS $$
+DECLARE
+out collections%ROWTYPE;
+BEGIN
+    UPDATE collections SET content=data WHERE id = data->>'id' RETURNING * INTO STRICT out;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+
+CREATE OR REPLACE FUNCTION upsert_collection(data jsonb) RETURNS VOID AS $$
+    INSERT INTO collections (content)
+    VALUES (data)
+    ON CONFLICT (id) DO
+    UPDATE
+        SET content=EXCLUDED.content
+    ;
+$$ LANGUAGE SQL SET SEARCH_PATH TO pgstac, public;
+
+CREATE OR REPLACE FUNCTION delete_collection(_id text) RETURNS VOID AS $$
+DECLARE
+out collections%ROWTYPE;
+BEGIN
+    DELETE FROM collections WHERE id = _id RETURNING * INTO STRICT out;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+
+
+CREATE OR REPLACE FUNCTION get_collection(id text) RETURNS jsonb AS $$
+SELECT content FROM collections
+WHERE id=$1
+;
+$$ LANGUAGE SQL SET SEARCH_PATH TO pgstac, public;
+
+CREATE OR REPLACE FUNCTION all_collections() RETURNS jsonb AS $$
+SELECT jsonb_agg(content) FROM collections;
+;
+$$ LANGUAGE SQL SET SEARCH_PATH TO pgstac, public;
+SET SEARCH_PATH TO pgstac, public;
+
+CREATE TABLE IF NOT EXISTS items (
+    id VARCHAR GENERATED ALWAYS AS (content->>'id') STORED NOT NULL,
+    geometry geometry GENERATED ALWAYS AS (stac_geom(content)) STORED NOT NULL,
+    properties jsonb GENERATED ALWAYS as (properties_idx(content->'properties')) STORED,
+    collection_id text GENERATED ALWAYS AS (content->>'collection') STORED NOT NULL,
+    datetime timestamptz GENERATED ALWAYS AS (stac_datetime(content)) STORED NOT NULL,
+    content JSONB NOT NULL
+)
+PARTITION BY RANGE (stac_datetime(content))
+;
+
+ALTER TABLE items ADD constraint items_collections_fk FOREIGN KEY (collection_id) REFERENCES collections(id) DEFERRABLE;
+
+CREATE TABLE items_template (
+    LIKE items
+);
+
+ALTER TABLE items_template ADD PRIMARY KEY (id);
+
+
+DELETE from partman.part_config WHERE parent_table = 'pgstac.items';
+SELECT partman.create_parent(
+    'pgstac.items',
+    'datetime',
+    'native',
+    'weekly',
+    p_template_table := 'pgstac.items_template',
+    p_premake := 4
+);
+
+CREATE OR REPLACE FUNCTION make_partitions(st timestamptz, et timestamptz DEFAULT NULL) RETURNS BOOL AS $$
+WITH t AS (
+    SELECT
+        generate_series(
+            date_trunc('week',st),
+            date_trunc('week', coalesce(et, st)),
+            '1 week'::interval
+        ) w
+),
+w AS (SELECT array_agg(w) as w FROM t)
+SELECT CASE WHEN w IS NULL THEN NULL ELSE partman.create_partition_time('pgstac.items', w, true) END FROM w;
+$$ LANGUAGE SQL;
+
+CREATE OR REPLACE FUNCTION get_partition(timestamptz) RETURNS text AS $$
+SELECT to_char($1, '"items_p"IYYY"w"IW');
+$$ LANGUAGE SQL;
+
+CREATE INDEX "datetime_id_idx" ON items (datetime, id);
+CREATE INDEX "properties_idx" ON items USING GIN (properties);
+CREATE INDEX "collection_idx" ON items (collection_id);
+CREATE INDEX "geometry_idx" ON items USING GIST (geometry);
+
+
+CREATE TYPE item AS (
+    id text,
+    geometry geometry,
+    properties JSONB,
+    collection_id text,
+    datetime timestamptz
+);
+
+
+CREATE OR REPLACE FUNCTION get_item(_id text) RETURNS jsonb AS $$
+    SELECT content FROM items WHERE id=_id;
+$$ LANGUAGE SQL SET SEARCH_PATH TO pgstac,public;
+
+CREATE OR REPLACE FUNCTION delete_item(_id text) RETURNS VOID AS $$
+DECLARE
+out items%ROWTYPE;
+BEGIN
+    DELETE FROM items WHERE id = _id RETURNING * INTO STRICT out;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+
+CREATE OR REPLACE FUNCTION create_item(data jsonb) RETURNS VOID AS $$
+    SELECT make_partitions(stac_datetime(data));
+    INSERT INTO items (content) VALUES (data);
+$$ LANGUAGE SQL SET SEARCH_PATH TO pgstac,public;
+
+
+CREATE OR REPLACE FUNCTION update_item(data jsonb) RETURNS VOID AS $$
+DECLARE
+out items%ROWTYPE;
+BEGIN
+    UPDATE items SET content=data WHERE id = data->>'id' RETURNING * INTO STRICT out;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+
+CREATE OR REPLACE FUNCTION upsert_item(data jsonb) RETURNS VOID AS $$
+DECLARE
+partition text;
+q text;
+newcontent jsonb;
+BEGIN
+    PERFORM make_partitions(stac_datetime(data));
+    partition := get_partition(stac_datetime(data));
+    q := format($q$
+        INSERT INTO %I (content) VALUES ($1)
+        ON CONFLICT (id) DO
+        UPDATE SET content = EXCLUDED.content
+        WHERE %I.content IS DISTINCT FROM EXCLUDED.content RETURNING content;
+        $q$, partition, partition);
+    EXECUTE q INTO newcontent USING (data);
+    RAISE NOTICE 'newcontent: %', newcontent;
+    RETURN;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+
+
+CREATE OR REPLACE FUNCTION analyze_empty_partitions() RETURNS VOID AS $$
+DECLARE
+p text;
+BEGIN
+FOR p IN SELECT partition FROM all_items_partitions WHERE est_cnt = 0 LOOP
+    RAISE NOTICE 'Analyzing %', p;
+    EXECUTE format('ANALYZE %I;', p);
+END LOOP;
+END;
+$$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION backfill_partitions()
+RETURNS VOID AS $$
+DECLARE
+BEGIN
+    IF EXISTS (SELECT 1 FROM items_default LIMIT 1) THEN
+        RAISE NOTICE 'Creating new partitions and moving data from default';
+        CREATE TEMP TABLE items_default_tmp ON COMMIT DROP AS SELECT datetime, content FROM items_default;
+        TRUNCATE items_default;
+        PERFORM make_partitions(min(datetime), max(datetime)) FROM items_default_tmp;
+        INSERT INTO items (content) SELECT content FROM items_default_tmp;
+    END IF;
+    RETURN;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+
+CREATE OR REPLACE FUNCTION items_trigger_stmt_func()
+RETURNS TRIGGER AS $$
+DECLARE
+BEGIN
+    PERFORM analyze_empty_partitions();
+    RETURN NULL;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+
+DROP TRIGGER IF EXISTS items_stmt_trigger ON items;
+CREATE TRIGGER items_stmt_trigger
+AFTER INSERT OR UPDATE OR DELETE ON items
+FOR EACH STATEMENT EXECUTE PROCEDURE items_trigger_stmt_func();
+
+
+/*
+View to get a table of available items partitions
+with date ranges
+*/
+--DROP VIEW IF EXISTS all_items_partitions CASCADE;
+CREATE OR REPLACE VIEW all_items_partitions AS
+WITH base AS
+(SELECT
+    c.oid::pg_catalog.regclass::text as partition,
+    pg_catalog.pg_get_expr(c.relpartbound, c.oid) as _constraint,
+    regexp_matches(
+        pg_catalog.pg_get_expr(c.relpartbound, c.oid),
+        E'\\(''\([0-9 :+-]*\)''\\).*\\(''\([0-9 :+-]*\)''\\)'
+    ) as t,
+    reltuples::bigint as est_cnt
+FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+WHERE c.oid = i.inhrelid AND i.inhparent = 'items'::regclass)
+SELECT partition, tstzrange(
+    t[1]::timestamptz,
+    t[2]::timestamptz
+), est_cnt
+FROM base
+ORDER BY 2 desc;
+
+--DROP VIEW IF EXISTS items_partitions;
+CREATE OR REPLACE VIEW items_partitions AS
+SELECT * FROM all_items_partitions WHERE est_cnt>0;
+
+CREATE OR REPLACE FUNCTION collection_bbox(id text) RETURNS jsonb AS $$
+SELECT (replace(replace(replace(st_extent(geometry)::text,'BOX(','[['),')',']]'),' ',','))::jsonb
+FROM items WHERE collection_id=$1;
+;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE SET SEARCH_PATH TO pgstac, public;
+
+CREATE OR REPLACE FUNCTION collection_temporal_extent(id text) RETURNS jsonb AS $$
+SELECT to_jsonb(array[array[min(datetime)::text, max(datetime)::text]])
+FROM items WHERE collection_id=$1;
+;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE SET SEARCH_PATH TO pgstac, public;
+
+CREATE OR REPLACE FUNCTION update_collection_extents() RETURNS VOID AS $$
+UPDATE collections SET
+    content = content ||
+    jsonb_build_object(
+        'extent', jsonb_build_object(
+            'spatial', jsonb_build_object(
+                'bbox', collection_bbox(collections.id)
+            ),
+            'temporal', jsonb_build_object(
+                'interval', collection_temporal_extent(collections.id)
+            )
+        )
+    )
+;
+$$ LANGUAGE SQL SET SEARCH_PATH TO pgstac, public;
+SET SEARCH_PATH TO pgstac, public;
+
+
+CREATE OR REPLACE FUNCTION items_by_partition(
+    IN _where text DEFAULT 'TRUE',
+    IN _dtrange tstzrange DEFAULT tstzrange('-infinity','infinity'),
+    IN _orderby text DEFAULT 'datetime DESC, id DESC',
+    IN _limit int DEFAULT 10
+) RETURNS SETOF items AS $$
+DECLARE
+partition_query text;
+main_query text;
+batchcount int;
+counter int := 0;
+p record;
+BEGIN
+IF _orderby ILIKE 'datetime d%' THEN
+    partition_query := format($q$
+        SELECT partition
+        FROM items_partitions
+        WHERE tstzrange && $1
+        ORDER BY tstzrange DESC;
+    $q$);
+ELSIF _orderby ILIKE 'datetime a%' THEN
+    partition_query := format($q$
+        SELECT partition
+        FROM items_partitions
+        WHERE tstzrange && $1
+        ORDER BY tstzrange ASC
+        ;
+    $q$);
+ELSE
+    partition_query := format($q$
+        SELECT 'items' as partition WHERE $1 IS NOT NULL;
+    $q$);
+END IF;
+RAISE NOTICE 'Partition Query: %', partition_query;
+FOR p IN
+    EXECUTE partition_query USING (_dtrange)
+LOOP
+    IF lower(_dtrange)::timestamptz > '-infinity' THEN
+        _where := concat(_where,format(' AND datetime >= %L',lower(_dtrange)::timestamptz::text));
+    END IF;
+    IF upper(_dtrange)::timestamptz < 'infinity' THEN
+        _where := concat(_where,format(' AND datetime <= %L',upper(_dtrange)::timestamptz::text));
+    END IF;
+
+    main_query := format($q$
+        SELECT * FROM %I
+        WHERE %s
+        ORDER BY %s
+        LIMIT %s - $1
+    $q$, p.partition::text, _where, _orderby, _limit
+    );
+    RAISE NOTICE 'Partition Query %', main_query;
+    RAISE NOTICE '%', counter;
+    RETURN QUERY EXECUTE main_query USING counter;
+
+    GET DIAGNOSTICS batchcount = ROW_COUNT;
+    counter := counter + batchcount;
+    RAISE NOTICE 'FOUND %', batchcount;
+    IF counter >= _limit THEN
+        EXIT;
+    END IF;
+    RAISE NOTICE 'ADDED % FOR A TOTAL OF %', batchcount, counter;
+END LOOP;
+RETURN;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+
+
+CREATE OR REPLACE FUNCTION split_stac_path(IN path text, OUT col text, OUT dotpath text, OUT jspath text, OUT jspathtext text) AS $$
+WITH col AS (
+    SELECT
+        CASE WHEN
+            split_part(path, '.', 1) IN ('id', 'stac_version', 'stac_extensions','geometry','properties','assets','collection_id','datetime','links', 'extra_fields') THEN split_part(path, '.', 1)
+        ELSE 'properties'
+        END AS col
+),
+dp AS (
+    SELECT
+        col, ltrim(replace(path, col , ''),'.') as dotpath
+    FROM col
+),
+paths AS (
+SELECT
+    col, dotpath,
+    regexp_split_to_table(dotpath,E'\\.') as path FROM dp
+) SELECT
+    col,
+    btrim(concat(col,'.',dotpath),'.'),
+    CASE WHEN btrim(concat(col,'.',dotpath),'.') != col THEN concat(col,'->',string_agg(concat('''',path,''''),'->')) ELSE col END,
+    regexp_replace(
+        CASE WHEN btrim(concat(col,'.',dotpath),'.') != col THEN concat(col,'->',string_agg(concat('''',path,''''),'->')) ELSE col END,
+        E'>([^>]*)$','>>\1'
+    )
+FROM paths group by col, dotpath;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+
+/* Functions for searching items */
+CREATE OR REPLACE FUNCTION sort_base(
+    IN _sort jsonb DEFAULT '[{"field":"datetime","direction":"desc"}]',
+    OUT key text,
+    OUT col text,
+    OUT dir text,
+    OUT rdir text,
+    OUT sort text,
+    OUT rsort text
+) RETURNS SETOF RECORD AS $$
+WITH sorts AS (
+    SELECT
+        value->>'field' as key,
+        (split_stac_path(value->>'field')).jspathtext as col,
+        coalesce(upper(value->>'direction'),'ASC') as dir
+    FROM jsonb_array_elements('[]'::jsonb || coalesce(_sort,'[{"field":"datetime","direction":"desc"}]') )
+)
+SELECT
+    key,
+    col,
+    dir,
+    CASE dir WHEN 'DESC' THEN 'ASC' ELSE 'ASC' END as rdir,
+    concat(col, ' ', dir, ' NULLS LAST ') AS sort,
+    concat(col,' ', CASE dir WHEN 'DESC' THEN 'ASC' ELSE 'ASC' END, ' NULLS LAST ') AS rsort
+FROM sorts
+UNION ALL
+SELECT 'id', 'id', 'DESC', 'ASC', 'id DESC', 'id ASC'
+;
+$$ LANGUAGE SQL;
+
+
+CREATE OR REPLACE FUNCTION sort(_sort jsonb) RETURNS text AS $$
+SELECT string_agg(sort,', ') FROM sort_base(_sort);
+$$ LANGUAGE SQL PARALLEL SAFE SET SEARCH_PATH TO pgstac,public;
+
+
+CREATE OR REPLACE FUNCTION rsort(_sort jsonb) RETURNS text AS $$
+SELECT string_agg(rsort,', ') FROM sort_base(_sort);
+$$ LANGUAGE SQL PARALLEL SAFE SET SEARCH_PATH TO pgstac,public;
+
+
+CREATE OR REPLACE FUNCTION bbox_geom(_bbox jsonb) RETURNS geometry AS $$
+SELECT CASE jsonb_array_length(_bbox)
+    WHEN 4 THEN
+        ST_SetSRID(ST_MakeEnvelope(
+            (_bbox->>0)::float,
+            (_bbox->>1)::float,
+            (_bbox->>2)::float,
+            (_bbox->>3)::float
+        ),4326)
+    WHEN 6 THEN
+    ST_SetSRID(ST_3DMakeBox(
+        ST_MakePoint(
+            (_bbox->>0)::float,
+            (_bbox->>1)::float,
+            (_bbox->>2)::float
+        ),
+        ST_MakePoint(
+            (_bbox->>3)::float,
+            (_bbox->>4)::float,
+            (_bbox->>5)::float
+        )
+    ),4326)
+    ELSE null END;
+;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION in_array_q(col text, arr jsonb) RETURNS text AS $$
+SELECT CASE jsonb_typeof(arr) WHEN 'array' THEN format('%I = ANY(textarr(%L))', col, arr) ELSE format('%I = %L', col, arr) END;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION count_by_delim(text, text) RETURNS int AS $$
+SELECT count(*) FROM regexp_split_to_table($1,$2);
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+
+
+CREATE OR REPLACE FUNCTION stac_query_op(att text, _op text, val jsonb) RETURNS text AS $$
+DECLARE
+ret text := '';
+op text;
+jp text;
+att_parts RECORD;
+val_str text;
+prop_path text;
+BEGIN
+val_str := lower(jsonb_build_object('a',val)->>'a');
+RAISE NOTICE 'val_str %', val_str;
+
+att_parts := split_stac_path(att);
+prop_path := replace(att_parts.dotpath, 'properties.', '');
+
+op := CASE _op
+    WHEN 'eq' THEN '='
+    WHEN 'gte' THEN '>='
+    WHEN 'gt' THEN '>'
+    WHEN 'lte' THEN '<='
+    WHEN 'lt' THEN '<'
+    WHEN 'ne' THEN '!='
+    WHEN 'neq' THEN '!='
+    WHEN 'startsWith' THEN 'LIKE'
+    WHEN 'endsWith' THEN 'LIKE'
+    WHEN 'contains' THEN 'LIKE'
+    ELSE _op
+END;
+
+val_str := CASE _op
+    WHEN 'startsWith' THEN concat(val_str, '%')
+    WHEN 'endsWith' THEN concat('%', val_str)
+    WHEN 'contains' THEN concat('%',val_str,'%')
+    ELSE val_str
+END;
+
+
+RAISE NOTICE 'att_parts: % %', att_parts, count_by_delim(att_parts.dotpath,'\.');
+IF
+    op = '='
+    AND att_parts.col = 'properties'
+    --AND count_by_delim(att_parts.dotpath,'\.') = 2
+THEN
+    -- use jsonpath query to leverage index for eqaulity tests on single level deep properties
+    jp := btrim(format($jp$ $.%I[*] ? ( @ == %s ) $jp$, replace(att_parts.dotpath, 'properties.',''), lower(val::text)::jsonb));
+    raise notice 'jp: %', jp;
+    ret := format($q$ properties @? %L $q$, jp);
+ELSIF jsonb_typeof(val) = 'number' THEN
+    ret := format('properties ? %L AND (%s)::numeric %s %s', prop_path, att_parts.jspathtext, op, val);
+ELSE
+    ret := format('properties ? %L AND %s %s %L', prop_path ,att_parts.jspathtext, op, val_str);
+END IF;
+RAISE NOTICE 'Op Query: %', ret;
+
+return ret;
+END;
+$$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION stac_query(_query jsonb) RETURNS TEXT[] AS $$
+DECLARE
+qa text[];
+att text;
+ops jsonb;
+op text;
+val jsonb;
+BEGIN
+FOR att, ops IN SELECT key, value FROM jsonb_each(_query)
+LOOP
+    FOR op, val IN SELECT key, value FROM jsonb_each(ops)
+    LOOP
+        qa := array_append(qa, stac_query_op(att,op, val));
+        RAISE NOTICE '% % %', att, op, val;
+    END LOOP;
+END LOOP;
+RETURN qa;
+END;
+$$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION filter_by_order(item_id text, _sort jsonb, _type text) RETURNS text AS $$
+DECLARE
+item item;
+BEGIN
+SELECT * INTO item FROM items WHERE id=item_id;
+RETURN filter_by_order(item, _sort, _type);
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+
+-- Used to create filters used for paging using the items id from the token
+CREATE OR REPLACE FUNCTION filter_by_order(_item item, _sort jsonb, _type text) RETURNS text AS $$
+DECLARE
+sorts RECORD;
+filts text[];
+itemval text;
+op text;
+idop text;
+ret text;
+eq_flag text;
+_item_j jsonb := to_jsonb(_item);
+BEGIN
+FOR sorts IN SELECT * FROM sort_base(_sort) LOOP
+    IF sorts.col = 'datetime' THEN
+        CONTINUE;
+    END IF;
+    IF sorts.col='id' AND _type IN ('prev','next') THEN
+        eq_flag := '';
+    ELSE
+        eq_flag := '=';
+    END IF;
+
+    op := concat(
+        CASE
+            WHEN _type in ('prev','first') AND sorts.dir = 'ASC' THEN '<'
+            WHEN _type in ('last','next') AND sorts.dir = 'ASC' THEN '>'
+            WHEN _type in ('prev','first') AND sorts.dir = 'DESC' THEN '>'
+            WHEN _type in ('last','next') AND sorts.dir = 'DESC' THEN '<'
+        END,
+        eq_flag
+    );
+
+    IF _item_j ? sorts.col THEN
+        filts = array_append(filts, format('%s %s %L', sorts.col, op, _item_j->>sorts.col));
+    END IF;
+END LOOP;
+ret := coalesce(array_to_string(filts,' AND '), 'TRUE');
+RAISE NOTICE 'Order Filter %', ret;
+RETURN ret;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+
+CREATE OR REPLACE FUNCTION search_dtrange(IN _indate jsonb, OUT _tstzrange tstzrange) AS
+$$
+WITH t AS (
+    SELECT CASE
+        WHEN jsonb_typeof(_indate) = 'array' THEN
+            textarr(_indate)
+        ELSE
+            regexp_split_to_array(
+                btrim(_indate::text,'"'),
+                '/'
+            )
+        END AS arr
+)
+, t1 AS (
+    SELECT
+        CASE
+            WHEN array_upper(arr,1) = 1 OR arr[1] = '..' OR arr[1] IS NULL THEN '-infinity'::timestamptz
+            ELSE arr[1]::timestamptz
+        END AS st,
+        CASE
+            WHEN array_upper(arr,1) = 1 THEN arr[1]::timestamptz
+            WHEN arr[2] = '..' OR arr[2] IS NULL THEN 'infinity'::timestamptz
+            ELSE arr[2]::timestamptz
+        END AS et
+    FROM t
+)
+SELECT
+    tstzrange(st,et)
+FROM t1;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION flip_jsonb_array(j jsonb) RETURNS jsonb AS $$
+WITH t AS (
+    SELECT i, row_number() over () as r FROM jsonb_array_elements(j) i
+), o AS (
+    SELECT i FROM t ORDER BY r DESC
+)
+SELECT jsonb_agg(i) from o
+;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+
+CREATE OR REPLACE FUNCTION search(_search jsonb = '{}'::jsonb) RETURNS SETOF jsonb AS $$
+DECLARE
+qstart timestamptz := clock_timestamp();
+_sort text := '';
+_rsort text := '';
+_limit int := 10;
+_geom geometry;
+qa text[];
+pq text[];
+query text;
+pq_prop record;
+pq_op record;
+prev_id text := NULL;
+next_id text := NULL;
+whereq text := 'TRUE';
+links jsonb := '[]'::jsonb;
+token text;
+tok_val text;
+tok_q text := 'TRUE';
+tok_sort text;
+first_id text;
+first_dt timestamptz;
+last_id text;
+sort text;
+rsort text;
+dt text[];
+dqa text[];
+dq text;
+mq_where text;
+startdt timestamptz;
+enddt timestamptz;
+item items%ROWTYPE;
+counter int := 0;
+batchcount int;
+month timestamptz;
+m record;
+_dtrange tstzrange := tstzrange('-infinity','infinity');
+_dtsort text;
+_token_dtrange tstzrange := tstzrange('-infinity','infinity');
+_token_record items%ROWTYPE;
+is_prev boolean := false;
+includes text[];
+excludes text[];
+BEGIN
+-- Create table from sort query of items to sort
+CREATE TEMP TABLE pgstac_tmp_sorts ON COMMIT DROP AS SELECT * FROM sort_base(_search->'sortby');
+
+-- Get the datetime sort direction, necessary for efficient cycling through partitions
+SELECT INTO _dtsort dir FROM pgstac_tmp_sorts WHERE key='datetime';
+RAISE NOTICE '_dtsort: %',_dtsort;
+
+SELECT INTO _sort string_agg(s.sort,', ') FROM pgstac_tmp_sorts s;
+SELECT INTO _rsort string_agg(s.rsort,', ') FROM pgstac_tmp_sorts s;
+tok_sort := _sort;
+
+
+-- Get datetime from query as a tstzrange
+IF _search ? 'datetime' THEN
+    _dtrange := search_dtrange(_search->'datetime');
+    _token_dtrange := _dtrange;
+END IF;
+
+-- Get the paging token
+IF _search ? 'token' THEN
+    token := _search->>'token';
+    tok_val := substr(token,6);
+    IF starts_with(token, 'prev:') THEN
+        is_prev := true;
+    END IF;
+    SELECT INTO _token_record * FROM items WHERE id=tok_val;
+    IF
+        (is_prev AND _dtsort = 'DESC')
+        OR
+        (not is_prev AND _dtsort = 'ASC')
+    THEN
+        _token_dtrange := _dtrange * tstzrange(_token_record.datetime, 'infinity');
+    ELSIF
+        _dtsort IS NOT NULL
+    THEN
+        _token_dtrange := _dtrange * tstzrange('-infinity',_token_record.datetime);
+    END IF;
+    IF is_prev THEN
+        tok_q := filter_by_order(tok_val,  _search->'sortby', 'first');
+        _sort := _rsort;
+    ELSIF starts_with(token, 'next:') THEN
+       tok_q := filter_by_order(tok_val,  _search->'sortby', 'last');
+    END IF;
+END IF;
+RAISE NOTICE 'timing: %', age(clock_timestamp(), qstart);
+RAISE NOTICE 'tok_q: % _token_dtrange: %', tok_q, _token_dtrange;
+
+IF _search ? 'ids' THEN
+    RAISE NOTICE 'searching solely based on ids... %',_search;
+    qa := array_append(qa, in_array_q('id', _search->'ids'));
+ELSE
+    IF _search ? 'intersects' THEN
+        _geom := ST_SetSRID(ST_GeomFromGeoJSON(_search->>'intersects'), 4326);
+    ELSIF _search ? 'bbox' THEN
+        _geom := bbox_geom(_search->'bbox');
+    END IF;
+
+    IF _geom IS NOT NULL THEN
+        qa := array_append(qa, format('st_intersects(geometry, %L::geometry)',_geom));
+    END IF;
+
+    IF _search ? 'collections' THEN
+        qa := array_append(qa, in_array_q('collection_id', _search->'collections'));
+    END IF;
+
+    IF _search ? 'query' THEN
+        qa := array_cat(qa,
+            stac_query(_search->'query')
+        );
+    END IF;
+END IF;
+
+IF _search ? 'limit' THEN
+    _limit := (_search->>'limit')::int;
+END IF;
+
+IF _search ? 'fields' THEN
+    IF _search->'fields' ? 'exclude' THEN
+        excludes=textarr(_search->'fields'->'exclude');
+    END IF;
+    IF _search->'fields' ? 'include' THEN
+        includes=textarr(_search->'fields'->'include');
+        IF array_length(includes, 1)>0 AND NOT 'id' = ANY (includes) THEN
+            includes = includes || '{id}';
+        END IF;
+    END IF;
+    RAISE NOTICE 'Includes: %, Excludes: %', includes, excludes;
+END IF;
+
+whereq := COALESCE(array_to_string(qa,' AND '),' TRUE ');
+dq := COALESCE(array_to_string(dqa,' AND '),' TRUE ');
+RAISE NOTICE 'timing before temp table: %', age(clock_timestamp(), qstart);
+
+CREATE TEMP TABLE results_page ON COMMIT DROP AS
+SELECT * FROM items_by_partition(
+    concat(whereq, ' AND ', tok_q),
+    _token_dtrange,
+    _sort,
+    _limit + 1
+);
+RAISE NOTICE 'timing after temp table: %', age(clock_timestamp(), qstart);
+
+RAISE NOTICE 'timing before min/max: %', age(clock_timestamp(), qstart);
+
+IF is_prev THEN
+    SELECT INTO last_id, first_id, counter
+        first_value(id) OVER (),
+        last_value(id) OVER (),
+        count(*) OVER ()
+    FROM results_page;
+ELSE
+    SELECT INTO first_id, last_id, counter
+        first_value(id) OVER (),
+        last_value(id) OVER (),
+        count(*) OVER ()
+    FROM results_page;
+END IF;
+RAISE NOTICE 'firstid: %, lastid %', first_id, last_id;
+RAISE NOTICE 'timing after min/max: %', age(clock_timestamp(), qstart);
+
+
+
+
+IF counter > _limit THEN
+    next_id := last_id;
+    RAISE NOTICE 'next_id: %', next_id;
+ELSE
+    RAISE NOTICE 'No more next';
+END IF;
+
+IF tok_q = 'TRUE' THEN
+    RAISE NOTICE 'Not a paging query, no previous item';
+ELSE
+    RAISE NOTICE 'Getting previous item id';
+    RAISE NOTICE 'timing: %', age(clock_timestamp(), qstart);
+    SELECT INTO _token_record * FROM items WHERE id=first_id;
+    IF
+        _dtsort = 'DESC'
+    THEN
+        _token_dtrange := _dtrange * tstzrange(_token_record.datetime, 'infinity');
+    ELSE
+        _token_dtrange := _dtrange * tstzrange('-infinity',_token_record.datetime);
+    END IF;
+    RAISE NOTICE '% %', _token_dtrange, _dtrange;
+    SELECT id INTO prev_id FROM items_by_partition(
+        concat(whereq, ' AND ', filter_by_order(first_id, _search->'sortby', 'prev')),
+        _token_dtrange,
+        _rsort,
+        1
+    );
+    RAISE NOTICE 'timing: %', age(clock_timestamp(), qstart);
+
+    RAISE NOTICE 'prev_id: %', prev_id;
+END IF;
+
+
+RETURN QUERY
+WITH features AS (
+    SELECT filter_jsonb(content, includes, excludes) as content
+    FROM results_page LIMIT _limit
+),
+j AS (SELECT jsonb_agg(content) as feature_arr FROM features)
+SELECT jsonb_build_object(
+    'type', 'FeatureCollection',
+    'features', coalesce (
+        CASE WHEN is_prev THEN flip_jsonb_array(feature_arr) ELSE feature_arr END
+        ,'[]'::jsonb),
+    'links', links,
+    'timeStamp', now(),
+    'next', next_id,
+    'prev', prev_id
+)
+FROM j
+;
+
+
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+INSERT INTO pgstac.migrations (version) VALUES ('0.2.9');
diff --git a/pypgstac/pyproject.toml b/pypgstac/pyproject.toml
index 0a86ddd4..d896fc88 100644
--- a/pypgstac/pyproject.toml
+++ b/pypgstac/pyproject.toml
@@ -1,6 +1,6 @@
 [tool.poetry]
 name = "pypgstac"
-version = "0.2.8"
+version = "0.2.9"
 description = ""
 authors = ["David Bitner <bitner@dbspatial.com>"]
 keywords = ["stac", "asyncpg"]
diff --git a/sql/999_version.sql b/sql/999_version.sql
index 6a97f424..ed324491 100644
--- a/sql/999_version.sql
+++ b/sql/999_version.sql
@@ -1 +1 @@
-INSERT INTO pgstac.migrations (version) VALUES ('0.2.8');
+INSERT INTO pgstac.migrations (version) VALUES ('0.2.9');

From 2e4bd643232f4d818e81f78490f2c8be2a9295a9 Mon Sep 17 00:00:00 2001
From: vincentsarago <vincent.sarago@gmail.com>
Date: Thu, 19 Aug 2021 08:50:43 +0200
Subject: [PATCH 02/10] add tests to make sure search return an empty array

---
 test/pgtap/004_search.sql | 8 ++++++++
 1 file changed, 8 insertions(+)

diff --git a/test/pgtap/004_search.sql b/test/pgtap/004_search.sql
index 1af4935c..0ca08d0d 100644
--- a/test/pgtap/004_search.sql
+++ b/test/pgtap/004_search.sql
@@ -170,6 +170,14 @@ SELECT results_eq($$
     'Test collections search with unknow collection'
 );
 
+SELECT results_eq($$
+    select s from search('{"collections":["something"],"fields":{"include":["id"]}}') s;
+    $$,$$
+    select '{"next": null, "prev": null, "type": "FeatureCollection", "context": {"limit": 10, "matched": 0, "returned": 0}, "features": []}'::jsonb
+    $$,
+    'Test collections search return empty feature not null'
+);
+
 /* template
 SELECT results_eq($$
 

From 288e4a76c771876721c09a345530f66f261fd6b1 Mon Sep 17 00:00:00 2001
From: vincentsarago <vincent.sarago@gmail.com>
Date: Thu, 19 Aug 2021 10:31:16 +0200
Subject: [PATCH 03/10] try regex

---
 scripts/bin/migra_funcs | 4 ++--
 1 file changed, 2 insertions(+), 2 deletions(-)

diff --git a/scripts/bin/migra_funcs b/scripts/bin/migra_funcs
index 4c46cede..588345e8 100644
--- a/scripts/bin/migra_funcs
+++ b/scripts/bin/migra_funcs
@@ -45,9 +45,9 @@ export -f pgwait
 function pgtap(){
     TESTOUTPUT=$(psql -X -f $BASEDIR/test/pgtap.sql $1)
     echo "Checking if any tests are not ok on db $1"
-    if [[ $(echo "$TESTOUTPUT" | grep '^not') == 0 ]]; then
+    if [[ $(echo "$TESTOUTPUT" | grep -e '^not') == 0 ]]; then
         echo "PGTap tests failed."
-        echo "$TESTOUTPUT" | grep '^not'
+        echo "$TESTOUTPUT" | grep -e '^not'
         exit 1
     else
         echo "All PGTap Tests Passed!"

From 0ad1b0a938262c9c6f85371ce346413079487edf Mon Sep 17 00:00:00 2001
From: vincentsarago <vincent.sarago@gmail.com>
Date: Thu, 19 Aug 2021 10:35:59 +0200
Subject: [PATCH 04/10] see what is in it

---
 scripts/bin/migra_funcs | 1 +
 1 file changed, 1 insertion(+)

diff --git a/scripts/bin/migra_funcs b/scripts/bin/migra_funcs
index 588345e8..f7b66f1c 100644
--- a/scripts/bin/migra_funcs
+++ b/scripts/bin/migra_funcs
@@ -45,6 +45,7 @@ export -f pgwait
 function pgtap(){
     TESTOUTPUT=$(psql -X -f $BASEDIR/test/pgtap.sql $1)
     echo "Checking if any tests are not ok on db $1"
+    echo "$TESTOUTPUT"
     if [[ $(echo "$TESTOUTPUT" | grep -e '^not') == 0 ]]; then
         echo "PGTap tests failed."
         echo "$TESTOUTPUT" | grep -e '^not'

From e4762bf403f21bb7e0e2936616070c40903185cf Mon Sep 17 00:00:00 2001
From: vincentsarago <vincent.sarago@gmail.com>
Date: Thu, 19 Aug 2021 10:52:46 +0200
Subject: [PATCH 05/10] fix pgtap function and echo the whole log

---
 scripts/bin/migra_funcs | 5 ++---
 1 file changed, 2 insertions(+), 3 deletions(-)

diff --git a/scripts/bin/migra_funcs b/scripts/bin/migra_funcs
index f7b66f1c..5a7e5edd 100644
--- a/scripts/bin/migra_funcs
+++ b/scripts/bin/migra_funcs
@@ -45,10 +45,9 @@ export -f pgwait
 function pgtap(){
     TESTOUTPUT=$(psql -X -f $BASEDIR/test/pgtap.sql $1)
     echo "Checking if any tests are not ok on db $1"
-    echo "$TESTOUTPUT"
-    if [[ $(echo "$TESTOUTPUT" | grep -e '^not') == 0 ]]; then
+    if [[ $(echo "$TESTOUTPUT" | grep -e '^not') ]]; then
         echo "PGTap tests failed."
-        echo "$TESTOUTPUT" | grep -e '^not'
+        echo "$TESTOUTPUT"
         exit 1
     else
         echo "All PGTap Tests Passed!"

From 849ea95f7cec5652de029297b72d1d0ed8c8c286 Mon Sep 17 00:00:00 2001
From: vincentsarago <vincent.sarago@gmail.com>
Date: Thu, 19 Aug 2021 11:10:28 +0200
Subject: [PATCH 06/10] fix collections test

---
 test/pgtap.sql            | 2 +-
 test/pgtap/004_search.sql | 4 ++--
 2 files changed, 3 insertions(+), 3 deletions(-)

diff --git a/test/pgtap.sql b/test/pgtap.sql
index 46f4e286..039dd147 100644
--- a/test/pgtap.sql
+++ b/test/pgtap.sql
@@ -19,7 +19,7 @@ SET SEARCH_PATH TO pgstac, pgtap, public;
 SET CLIENT_MIN_MESSAGES TO 'warning';
 
 -- Plan the tests.
-SELECT plan(70);
+SELECT plan(75);
 --SELECT * FROM no_plan();
 
 -- Run the tests.
diff --git a/test/pgtap/004_search.sql b/test/pgtap/004_search.sql
index 0ca08d0d..e105a745 100644
--- a/test/pgtap/004_search.sql
+++ b/test/pgtap/004_search.sql
@@ -157,9 +157,9 @@ SELECT results_eq($$
 SELECT results_eq($$
     select s from search('{"collections":["pgstac-test-collection"],"fields":{"include":["id"]}, "limit": 1}') s;
     $$,$$
-    select '{"next": "20200307aC0870130w361200", "prev": null, "type": "FeatureCollection", "context": {"limit": 1, "matched": 100, "returned": 1}, "features": [{"id": "20200307aC0870130w361200"}]}'::jsonb
+    select '{"next": "pgstac-test-item-0003", "prev": null, "type": "FeatureCollection", "context": {"limit": 1, "matched": 100, "returned": 1}, "features": [{"id": "pgstac-test-item-0003"}]}'::jsonb
     $$,
-    'Test collections search with unknow collection'
+    'Test collections search with collection'
 );
 
 SELECT results_eq($$

From 10e9f17775a2b8615b666655149503fdeadf2ea1 Mon Sep 17 00:00:00 2001
From: vincentsarago <vincent.sarago@gmail.com>
Date: Thu, 19 Aug 2021 22:10:32 +0200
Subject: [PATCH 07/10] make sure features is at least []

---
 sql/004_search.sql | 4 +---
 1 file changed, 1 insertion(+), 3 deletions(-)

diff --git a/sql/004_search.sql b/sql/004_search.sql
index 9e01d508..165642cb 100644
--- a/sql/004_search.sql
+++ b/sql/004_search.sql
@@ -821,7 +821,6 @@ IF has_next OR token_type='prev' THEN
 END IF;
 
 
-
 -- include/exclude any fields following fields extension
 IF _search ? 'fields' THEN
     IF _search->'fields' ? 'exclude' THEN
@@ -836,7 +835,6 @@ IF _search ? 'fields' THEN
     SELECT jsonb_agg(filter_jsonb(row, includes, excludes)) INTO out_records FROM jsonb_array_elements(out_records) row;
 END IF;
 
-
 context := jsonb_strip_nulls(jsonb_build_object(
     'limit', _limit,
     'matched', total_count,
@@ -845,7 +843,7 @@ context := jsonb_strip_nulls(jsonb_build_object(
 
 collection := jsonb_build_object(
     'type', 'FeatureCollection',
-    'features', out_records,
+    'features', coalesce(out_records, '[]'::jsonb),
     'next', next,
     'prev', prev,
     'context', context

From 01591a1440573941edc07dfb393883559731d9e3 Mon Sep 17 00:00:00 2001
From: Vincent Sarago <vincent.sarago@gmail.com>
Date: Thu, 19 Aug 2021 22:11:34 +0200
Subject: [PATCH 08/10] Update test/pgtap/004_search.sql

---
 test/pgtap/004_search.sql | 2 +-
 1 file changed, 1 insertion(+), 1 deletion(-)

diff --git a/test/pgtap/004_search.sql b/test/pgtap/004_search.sql
index e105a745..696c73a5 100644
--- a/test/pgtap/004_search.sql
+++ b/test/pgtap/004_search.sql
@@ -159,7 +159,7 @@ SELECT results_eq($$
     $$,$$
     select '{"next": "pgstac-test-item-0003", "prev": null, "type": "FeatureCollection", "context": {"limit": 1, "matched": 100, "returned": 1}, "features": [{"id": "pgstac-test-item-0003"}]}'::jsonb
     $$,
-    'Test collections search with collection'
+    'Test collections search'
 );
 
 SELECT results_eq($$

From 1837cbde63c27ace7413faf58c226205ae94573f Mon Sep 17 00:00:00 2001
From: David Bitner <bitner@dbspatial.com>
Date: Mon, 23 Aug 2021 11:34:30 -0500
Subject: [PATCH 09/10] fix tests, add tests for ids vs id, fix bug with id vs
 ids, fix bug with collection vs collections

---
 .../migrations/pgstac.0.3.1-0.3.2.sql         | 293 +++++++++++++++++-
 pypgstac/pypgstac/migrations/pgstac.0.3.2.sql | 218 ++++++-------
 sql/004_search.sql                            | 214 ++++++-------
 test/pgtap.sql                                |   2 +-
 test/pgtap/004_search.sql                     |  21 +-
 5 files changed, 531 insertions(+), 217 deletions(-)

diff --git a/pypgstac/pypgstac/migrations/pgstac.0.3.1-0.3.2.sql b/pypgstac/pypgstac/migrations/pgstac.0.3.1-0.3.2.sql
index 825cdd56..0c59d0f1 100644
--- a/pypgstac/pypgstac/migrations/pgstac.0.3.1-0.3.2.sql
+++ b/pypgstac/pypgstac/migrations/pgstac.0.3.1-0.3.2.sql
@@ -9,12 +9,12 @@ DECLARE
 newprop jsonb;
 newprops jsonb := '[]'::jsonb;
 BEGIN
-IF j ? 'id' THEN
+IF j ? 'ids' THEN
     newprop := jsonb_build_object(
         'in',
         jsonb_build_array(
             '{"property":"id"}'::jsonb,
-            j->'id'
+            j->'ids'
         )
     );
     newprops := jsonb_insert(newprops, '{1}', newprop);
@@ -61,7 +61,7 @@ IF newprops IS NOT NULL AND jsonb_array_length(newprops) > 0 THEN
         j,
         '{filter}',
         cql_and_append(j, jsonb_build_object('and', newprops))
-    ) - '{id,collections,datetime,bbox,intersects}'::text[];
+    ) - '{ids,collections,datetime,bbox,intersects}'::text[];
 END IF;
 
 return j;
@@ -69,6 +69,293 @@ END;
 $function$
 ;
 
+CREATE OR REPLACE FUNCTION pgstac.get_token_filter(_search jsonb DEFAULT '{}'::jsonb, token_rec jsonb DEFAULT NULL::jsonb)
+ RETURNS text
+ LANGUAGE plpgsql
+AS $function$
+DECLARE
+    token_id text;
+    filters text[] := '{}'::text[];
+    prev boolean := TRUE;
+    field text;
+    dir text;
+    sort record;
+    orfilters text[] := '{}'::text[];
+    andfilters text[] := '{}'::text[];
+    output text;
+    token_where text;
+BEGIN
+    -- If no token provided return NULL
+    IF token_rec IS NULL THEN
+        IF NOT (_search ? 'token' AND
+                (
+                    (_search->>'token' ILIKE 'prev:%')
+                    OR
+                    (_search->>'token' ILIKE 'next:%')
+                )
+        ) THEN
+            RETURN NULL;
+        END IF;
+        prev := (_search->>'token' ILIKE 'prev:%');
+        token_id := substr(_search->>'token', 6);
+        SELECT to_jsonb(items) INTO token_rec FROM items WHERE id=token_id;
+    END IF;
+    RAISE NOTICE 'TOKEN ID: %', token_rec->'id';
+
+    CREATE TEMP TABLE sorts (
+        _row int GENERATED ALWAYS AS IDENTITY NOT NULL,
+        _field text PRIMARY KEY,
+        _dir text NOT NULL,
+        _val text
+    ) ON COMMIT DROP;
+
+    -- Make sure we only have distinct columns to sort with taking the first one we get
+    INSERT INTO sorts (_field, _dir)
+        SELECT
+            (items_path(value->>'field')).path,
+            get_sort_dir(value)
+        FROM
+            jsonb_array_elements(coalesce(_search->'sortby','[{"field":"datetime","direction":"desc"}]'))
+    ON CONFLICT DO NOTHING
+    ;
+    RAISE NOTICE 'sorts 1: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
+    -- Get the first sort direction provided. As the id is a primary key, if there are any
+    -- sorts after id they won't do anything, so make sure that id is the last sort item.
+    SELECT _dir INTO dir FROM sorts ORDER BY _row ASC LIMIT 1;
+    IF EXISTS (SELECT 1 FROM sorts WHERE _field = 'id') THEN
+        DELETE FROM sorts WHERE _row > (SELECT _row FROM sorts WHERE _field = 'id' ORDER BY _row ASC);
+    ELSE
+        INSERT INTO sorts (_field, _dir) VALUES ('id', dir);
+    END IF;
+
+    -- Add value from looked up item to the sorts table
+    UPDATE sorts SET _val=quote_literal(token_rec->>_field);
+
+    -- Check if all sorts are the same direction and use row comparison
+    -- to filter
+    RAISE NOTICE 'sorts 2: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
+
+    IF (SELECT count(DISTINCT _dir) FROM sorts) = 1 THEN
+        SELECT format(
+                '(%s) %s (%s)',
+                concat_ws(', ', VARIADIC array_agg(quote_ident(_field))),
+                CASE WHEN (prev AND dir = 'ASC') OR (NOT prev AND dir = 'DESC') THEN '<' ELSE '>' END,
+                concat_ws(', ', VARIADIC array_agg(_val))
+        ) INTO output FROM sorts
+        WHERE token_rec ? _field
+        ;
+    ELSE
+        FOR sort IN SELECT * FROM sorts ORDER BY _row asc LOOP
+            RAISE NOTICE 'SORT: %', sort;
+            IF sort._row = 1 THEN
+                orfilters := orfilters || format('(%s %s %s)',
+                    quote_ident(sort._field),
+                    CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
+                    sort._val
+                );
+            ELSE
+                orfilters := orfilters || format('(%s AND %s %s %s)',
+                    array_to_string(andfilters, ' AND '),
+                    quote_ident(sort._field),
+                    CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
+                    sort._val
+                );
+
+            END IF;
+            andfilters := andfilters || format('%s = %s',
+                quote_ident(sort._field),
+                sort._val
+            );
+        END LOOP;
+        output := array_to_string(orfilters, ' OR ');
+    END IF;
+    DROP TABLE IF EXISTS sorts;
+    token_where := concat('(',coalesce(output,'true'),')');
+    IF trim(token_where) = '' THEN
+        token_where := NULL;
+    END IF;
+    RAISE NOTICE 'TOKEN_WHERE: |%|',token_where;
+    RETURN token_where;
+    END;
+$function$
+;
+
+CREATE OR REPLACE FUNCTION pgstac.search(_search jsonb DEFAULT '{}'::jsonb)
+ RETURNS jsonb
+ LANGUAGE plpgsql
+ SET jit TO 'off'
+AS $function$
+DECLARE
+    searches searches%ROWTYPE;
+    _where text;
+    token_where text;
+    full_where text;
+    orderby text;
+    query text;
+    token_type text := substr(_search->>'token',1,4);
+    _limit int := coalesce((_search->>'limit')::int, 10);
+    curs refcursor;
+    cntr int := 0;
+    iter_record items%ROWTYPE;
+    first_record items%ROWTYPE;
+    last_record items%ROWTYPE;
+    out_records jsonb := '[]'::jsonb;
+    prev_query text;
+    next text;
+    prev_id text;
+    has_next boolean := false;
+    has_prev boolean := false;
+    prev text;
+    total_count bigint;
+    context jsonb;
+    collection jsonb;
+    includes text[];
+    excludes text[];
+    exit_flag boolean := FALSE;
+    batches int := 0;
+    timer timestamptz := clock_timestamp();
+BEGIN
+searches := search_query(_search);
+_where := searches._where;
+orderby := searches.orderby;
+total_count := coalesce(searches.total_count, searches.estimated_count);
+
+
+IF token_type='prev' THEN
+    token_where := get_token_filter(_search, null::jsonb);
+    orderby := sort_sqlorderby(_search, TRUE);
+END IF;
+IF token_type='next' THEN
+    token_where := get_token_filter(_search, null::jsonb);
+END IF;
+
+full_where := concat_ws(' AND ', _where, token_where);
+RAISE NOTICE 'FULL QUERY % %', full_where, clock_timestamp()-timer;
+timer := clock_timestamp();
+
+FOR query IN SELECT partition_queries(full_where, orderby) LOOP
+    timer := clock_timestamp();
+    query := format('%s LIMIT %L', query, _limit + 1);
+    RAISE NOTICE 'Partition Query: %', query;
+    batches := batches + 1;
+    curs = create_cursor(query);
+    LOOP
+        FETCH curs into iter_record;
+        EXIT WHEN NOT FOUND;
+        cntr := cntr + 1;
+        last_record := iter_record;
+        IF cntr = 1 THEN
+            first_record := last_record;
+        END IF;
+        IF cntr <= _limit THEN
+            out_records := out_records || last_record.content;
+        ELSIF cntr > _limit THEN
+            has_next := true;
+            exit_flag := true;
+            EXIT;
+        END IF;
+    END LOOP;
+    RAISE NOTICE 'Query took %', clock_timestamp()-timer;
+    timer := clock_timestamp();
+    EXIT WHEN exit_flag;
+END LOOP;
+RAISE NOTICE 'Scanned through % partitions.', batches;
+
+
+-- Flip things around if this was the result of a prev token query
+IF token_type='prev' THEN
+    out_records := flip_jsonb_array(out_records);
+    first_record := last_record;
+END IF;
+
+-- If this query has a token, see if there is data before the first record
+IF _search ? 'token' THEN
+    prev_query := format(
+        'SELECT 1 FROM items WHERE %s LIMIT 1',
+        concat_ws(
+            ' AND ',
+            _where,
+            trim(get_token_filter(_search, to_jsonb(first_record)))
+        )
+    );
+    RAISE NOTICE 'Query to get previous record: % --- %', prev_query, first_record;
+    EXECUTE prev_query INTO has_prev;
+    IF FOUND and has_prev IS NOT NULL THEN
+        RAISE NOTICE 'Query results from prev query: %', has_prev;
+        has_prev := TRUE;
+    END IF;
+END IF;
+has_prev := COALESCE(has_prev, FALSE);
+
+RAISE NOTICE 'token_type: %, has_next: %, has_prev: %', token_type, has_next, has_prev;
+IF has_prev THEN
+    prev := out_records->0->>'id';
+END IF;
+IF has_next OR token_type='prev' THEN
+    next := out_records->-1->>'id';
+END IF;
+
+
+-- include/exclude any fields following fields extension
+IF _search ? 'fields' THEN
+    IF _search->'fields' ? 'exclude' THEN
+        excludes=textarr(_search->'fields'->'exclude');
+    END IF;
+    IF _search->'fields' ? 'include' THEN
+        includes=textarr(_search->'fields'->'include');
+        IF array_length(includes, 1)>0 AND NOT 'id' = ANY (includes) THEN
+            includes = includes || '{id}';
+        END IF;
+    END IF;
+    SELECT jsonb_agg(filter_jsonb(row, includes, excludes)) INTO out_records FROM jsonb_array_elements(out_records) row;
+END IF;
+
+context := jsonb_strip_nulls(jsonb_build_object(
+    'limit', _limit,
+    'matched', total_count,
+    'returned', coalesce(jsonb_array_length(out_records), 0)
+));
+
+collection := jsonb_build_object(
+    'type', 'FeatureCollection',
+    'features', coalesce(out_records, '[]'::jsonb),
+    'next', next,
+    'prev', prev,
+    'context', context
+);
+
+RETURN collection;
+END;
+$function$
+;
+
+CREATE OR REPLACE FUNCTION pgstac.sort_sqlorderby(_search jsonb DEFAULT NULL::jsonb, reverse boolean DEFAULT false)
+ RETURNS text
+ LANGUAGE sql
+AS $function$
+WITH sortby AS (
+    SELECT coalesce(_search->'sortby','[{"field":"datetime", "direction":"desc"}]') as sort
+), withid AS (
+    SELECT CASE
+        WHEN sort @? '$[*] ? (@.field == "id")' THEN sort
+        ELSE sort || '[{"field":"id", "direction":"desc"}]'::jsonb
+        END as sort
+    FROM sortby
+), withid_rows AS (
+    SELECT jsonb_array_elements(sort) as value FROM withid
+),sorts AS (
+    SELECT
+        (items_path(value->>'field')).path as key,
+        parse_sort_dir(value->>'direction', reverse) as dir
+    FROM withid_rows
+)
+SELECT array_to_string(
+    array_agg(concat(key, ' ', dir)),
+    ', '
+) FROM sorts;
+$function$
+;
+
 
 
 INSERT INTO migrations (version) VALUES ('0.3.2');
diff --git a/pypgstac/pypgstac/migrations/pgstac.0.3.2.sql b/pypgstac/pypgstac/migrations/pgstac.0.3.2.sql
index fb922d3c..2b887455 100644
--- a/pypgstac/pypgstac/migrations/pgstac.0.3.2.sql
+++ b/pypgstac/pypgstac/migrations/pgstac.0.3.2.sql
@@ -870,12 +870,12 @@ DECLARE
 newprop jsonb;
 newprops jsonb := '[]'::jsonb;
 BEGIN
-IF j ? 'id' THEN
+IF j ? 'ids' THEN
     newprop := jsonb_build_object(
         'in',
         jsonb_build_array(
             '{"property":"id"}'::jsonb,
-            j->'id'
+            j->'ids'
         )
     );
     newprops := jsonb_insert(newprops, '{1}', newprop);
@@ -922,7 +922,7 @@ IF newprops IS NOT NULL AND jsonb_array_length(newprops) > 0 THEN
         j,
         '{filter}',
         cql_and_append(j, jsonb_build_object('and', newprops))
-    ) - '{id,collections,datetime,bbox,intersects}'::text[];
+    ) - '{ids,collections,datetime,bbox,intersects}'::text[];
 END IF;
 
 return j;
@@ -1233,17 +1233,21 @@ CREATE OR REPLACE FUNCTION sort_sqlorderby(
     _search jsonb DEFAULT NULL,
     reverse boolean DEFAULT FALSE
 ) RETURNS text AS $$
-WITH sorts AS (
+WITH sortby AS (
+    SELECT coalesce(_search->'sortby','[{"field":"datetime", "direction":"desc"}]') as sort
+), withid AS (
+    SELECT CASE
+        WHEN sort @? '$[*] ? (@.field == "id")' THEN sort
+        ELSE sort || '[{"field":"id", "direction":"desc"}]'::jsonb
+        END as sort
+    FROM sortby
+), withid_rows AS (
+    SELECT jsonb_array_elements(sort) as value FROM withid
+),sorts AS (
     SELECT
         (items_path(value->>'field')).path as key,
         parse_sort_dir(value->>'direction', reverse) as dir
-    FROM jsonb_array_elements(
-        '[]'::jsonb
-        ||
-        coalesce(_search->'sortby','[{"field":"datetime", "direction":"desc"}]')
-        ||
-        '[{"field":"id","direction":"desc"}]'::jsonb
-    )
+    FROM withid_rows
 )
 SELECT array_to_string(
     array_agg(concat(key, ' ', dir)),
@@ -1258,107 +1262,109 @@ $$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
 
 CREATE OR REPLACE FUNCTION get_token_filter(_search jsonb = '{}'::jsonb, token_rec jsonb DEFAULT NULL) RETURNS text AS $$
 DECLARE
-token_id text;
-filters text[] := '{}'::text[];
-prev boolean := TRUE;
-field text;
-dir text;
-sort record;
-orfilters text[] := '{}'::text[];
-andfilters text[] := '{}'::text[];
-output text;
-token_where text;
+    token_id text;
+    filters text[] := '{}'::text[];
+    prev boolean := TRUE;
+    field text;
+    dir text;
+    sort record;
+    orfilters text[] := '{}'::text[];
+    andfilters text[] := '{}'::text[];
+    output text;
+    token_where text;
 BEGIN
--- If no token provided return NULL
-IF token_rec IS NULL THEN
-    IF NOT (_search ? 'token' AND
-            (
-                (_search->>'token' ILIKE 'prev:%')
-                OR
-                (_search->>'token' ILIKE 'next:%')
-            )
-    ) THEN
-        RETURN NULL;
+    -- If no token provided return NULL
+    IF token_rec IS NULL THEN
+        IF NOT (_search ? 'token' AND
+                (
+                    (_search->>'token' ILIKE 'prev:%')
+                    OR
+                    (_search->>'token' ILIKE 'next:%')
+                )
+        ) THEN
+            RETURN NULL;
+        END IF;
+        prev := (_search->>'token' ILIKE 'prev:%');
+        token_id := substr(_search->>'token', 6);
+        SELECT to_jsonb(items) INTO token_rec FROM items WHERE id=token_id;
     END IF;
-    prev := (_search->>'token' ILIKE 'prev:%');
-    token_id := substr(_search->>'token', 6);
-    SELECT to_jsonb(items) INTO token_rec FROM items WHERE id=token_id;
-END IF;
-RAISE NOTICE 'TOKEN ID: %', token_rec->'id';
+    RAISE NOTICE 'TOKEN ID: %', token_rec->'id';
 
-CREATE TEMP TABLE sorts (
-    _row int GENERATED ALWAYS AS IDENTITY NOT NULL,
-    _field text PRIMARY KEY,
-    _dir text NOT NULL,
-    _val text
-) ON COMMIT DROP;
+    CREATE TEMP TABLE sorts (
+        _row int GENERATED ALWAYS AS IDENTITY NOT NULL,
+        _field text PRIMARY KEY,
+        _dir text NOT NULL,
+        _val text
+    ) ON COMMIT DROP;
 
--- Make sure we only have distinct columns to sort with taking the first one we get
-INSERT INTO sorts (_field, _dir)
-    SELECT
-        (items_path(value->>'field')).path,
-        get_sort_dir(value)
-    FROM
-        jsonb_array_elements(coalesce(_search->'sort','[{"field":"datetime","direction":"desc"}]'))
-ON CONFLICT DO NOTHING
-;
-
--- Get the first sort direction provided. As the id is a primary key, if there are any
--- sorts after id they won't do anything, so make sure that id is the last sort item.
-SELECT _dir INTO dir FROM sorts ORDER BY _row ASC LIMIT 1;
-IF EXISTS (SELECT 1 FROM sorts WHERE _field = 'id') THEN
-    DELETE FROM sorts WHERE _row > (SELECT _row FROM sorts WHERE _field = 'id');
-ELSE
-    INSERT INTO sorts (_field, _dir) VALUES ('id', dir);
-END IF;
-
--- Add value from looked up item to the sorts table
-UPDATE sorts SET _val=quote_literal(token_rec->>_field);
-
--- Check if all sorts are the same direction and use row comparison
--- to filter
-IF (SELECT count(DISTINCT _dir) FROM sorts) = 1 THEN
-    SELECT format(
-            '(%s) %s (%s)',
-            concat_ws(', ', VARIADIC array_agg(quote_ident(_field))),
-            CASE WHEN (prev AND dir = 'ASC') OR (NOT prev AND dir = 'DESC') THEN '<' ELSE '>' END,
-            concat_ws(', ', VARIADIC array_agg(_val))
-    ) INTO output FROM sorts
-    WHERE token_rec ? _field
+    -- Make sure we only have distinct columns to sort with taking the first one we get
+    INSERT INTO sorts (_field, _dir)
+        SELECT
+            (items_path(value->>'field')).path,
+            get_sort_dir(value)
+        FROM
+            jsonb_array_elements(coalesce(_search->'sortby','[{"field":"datetime","direction":"desc"}]'))
+    ON CONFLICT DO NOTHING
     ;
-ELSE
-    FOR sort IN SELECT * FROM sorts ORDER BY _row asc LOOP
-        RAISE NOTICE 'SORT: %', sort;
-        IF sort._row = 1 THEN
-            orfilters := orfilters || format('(%s %s %s)',
-                quote_ident(sort._field),
-                CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
-                sort._val
-            );
-        ELSE
-            orfilters := orfilters || format('(%s AND %s %s %s)',
-                array_to_string(andfilters, ' AND '),
+    RAISE NOTICE 'sorts 1: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
+    -- Get the first sort direction provided. As the id is a primary key, if there are any
+    -- sorts after id they won't do anything, so make sure that id is the last sort item.
+    SELECT _dir INTO dir FROM sorts ORDER BY _row ASC LIMIT 1;
+    IF EXISTS (SELECT 1 FROM sorts WHERE _field = 'id') THEN
+        DELETE FROM sorts WHERE _row > (SELECT _row FROM sorts WHERE _field = 'id' ORDER BY _row ASC);
+    ELSE
+        INSERT INTO sorts (_field, _dir) VALUES ('id', dir);
+    END IF;
+
+    -- Add value from looked up item to the sorts table
+    UPDATE sorts SET _val=quote_literal(token_rec->>_field);
+
+    -- Check if all sorts are the same direction and use row comparison
+    -- to filter
+    RAISE NOTICE 'sorts 2: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
+
+    IF (SELECT count(DISTINCT _dir) FROM sorts) = 1 THEN
+        SELECT format(
+                '(%s) %s (%s)',
+                concat_ws(', ', VARIADIC array_agg(quote_ident(_field))),
+                CASE WHEN (prev AND dir = 'ASC') OR (NOT prev AND dir = 'DESC') THEN '<' ELSE '>' END,
+                concat_ws(', ', VARIADIC array_agg(_val))
+        ) INTO output FROM sorts
+        WHERE token_rec ? _field
+        ;
+    ELSE
+        FOR sort IN SELECT * FROM sorts ORDER BY _row asc LOOP
+            RAISE NOTICE 'SORT: %', sort;
+            IF sort._row = 1 THEN
+                orfilters := orfilters || format('(%s %s %s)',
+                    quote_ident(sort._field),
+                    CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
+                    sort._val
+                );
+            ELSE
+                orfilters := orfilters || format('(%s AND %s %s %s)',
+                    array_to_string(andfilters, ' AND '),
+                    quote_ident(sort._field),
+                    CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
+                    sort._val
+                );
+
+            END IF;
+            andfilters := andfilters || format('%s = %s',
                 quote_ident(sort._field),
-                CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
                 sort._val
             );
-
-        END IF;
-        andfilters := andfilters || format('%s = %s',
-            quote_ident(sort._field),
-            sort._val
-        );
-    END LOOP;
-    output := array_to_string(orfilters, ' OR ');
-END IF;
-DROP TABLE IF EXISTS sorts;
-token_where := concat('(',coalesce(output,'true'),')');
-IF trim(token_where) = '' THEN
-    token_where := NULL;
-END IF;
-RAISE NOTICE 'TOKEN_WHERE: |%|',token_where;
-RETURN token_where;
-END;
+        END LOOP;
+        output := array_to_string(orfilters, ' OR ');
+    END IF;
+    DROP TABLE IF EXISTS sorts;
+    token_where := concat('(',coalesce(output,'true'),')');
+    IF trim(token_where) = '' THEN
+        token_where := NULL;
+    END IF;
+    RAISE NOTICE 'TOKEN_WHERE: |%|',token_where;
+    RETURN token_where;
+    END;
 $$ LANGUAGE PLPGSQL;
 
 CREATE OR REPLACE FUNCTION search_tohash(jsonb) RETURNS jsonb AS $$
@@ -1555,7 +1561,6 @@ IF has_next OR token_type='prev' THEN
 END IF;
 
 
-
 -- include/exclude any fields following fields extension
 IF _search ? 'fields' THEN
     IF _search->'fields' ? 'exclude' THEN
@@ -1570,7 +1575,6 @@ IF _search ? 'fields' THEN
     SELECT jsonb_agg(filter_jsonb(row, includes, excludes)) INTO out_records FROM jsonb_array_elements(out_records) row;
 END IF;
 
-
 context := jsonb_strip_nulls(jsonb_build_object(
     'limit', _limit,
     'matched', total_count,
@@ -1579,7 +1583,7 @@ context := jsonb_strip_nulls(jsonb_build_object(
 
 collection := jsonb_build_object(
     'type', 'FeatureCollection',
-    'features', out_records,
+    'features', coalesce(out_records, '[]'::jsonb),
     'next', next,
     'prev', prev,
     'context', context
diff --git a/sql/004_search.sql b/sql/004_search.sql
index 165642cb..4e4dbf1a 100644
--- a/sql/004_search.sql
+++ b/sql/004_search.sql
@@ -136,12 +136,12 @@ DECLARE
 newprop jsonb;
 newprops jsonb := '[]'::jsonb;
 BEGIN
-IF j ? 'id' THEN
+IF j ? 'ids' THEN
     newprop := jsonb_build_object(
         'in',
         jsonb_build_array(
             '{"property":"id"}'::jsonb,
-            j->'id'
+            j->'ids'
         )
     );
     newprops := jsonb_insert(newprops, '{1}', newprop);
@@ -188,7 +188,7 @@ IF newprops IS NOT NULL AND jsonb_array_length(newprops) > 0 THEN
         j,
         '{filter}',
         cql_and_append(j, jsonb_build_object('and', newprops))
-    ) - '{id,collections,datetime,bbox,intersects}'::text[];
+    ) - '{ids,collections,datetime,bbox,intersects}'::text[];
 END IF;
 
 return j;
@@ -499,17 +499,21 @@ CREATE OR REPLACE FUNCTION sort_sqlorderby(
     _search jsonb DEFAULT NULL,
     reverse boolean DEFAULT FALSE
 ) RETURNS text AS $$
-WITH sorts AS (
+WITH sortby AS (
+    SELECT coalesce(_search->'sortby','[{"field":"datetime", "direction":"desc"}]') as sort
+), withid AS (
+    SELECT CASE
+        WHEN sort @? '$[*] ? (@.field == "id")' THEN sort
+        ELSE sort || '[{"field":"id", "direction":"desc"}]'::jsonb
+        END as sort
+    FROM sortby
+), withid_rows AS (
+    SELECT jsonb_array_elements(sort) as value FROM withid
+),sorts AS (
     SELECT
         (items_path(value->>'field')).path as key,
         parse_sort_dir(value->>'direction', reverse) as dir
-    FROM jsonb_array_elements(
-        '[]'::jsonb
-        ||
-        coalesce(_search->'sortby','[{"field":"datetime", "direction":"desc"}]')
-        ||
-        '[{"field":"id","direction":"desc"}]'::jsonb
-    )
+    FROM withid_rows
 )
 SELECT array_to_string(
     array_agg(concat(key, ' ', dir)),
@@ -524,107 +528,109 @@ $$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
 
 CREATE OR REPLACE FUNCTION get_token_filter(_search jsonb = '{}'::jsonb, token_rec jsonb DEFAULT NULL) RETURNS text AS $$
 DECLARE
-token_id text;
-filters text[] := '{}'::text[];
-prev boolean := TRUE;
-field text;
-dir text;
-sort record;
-orfilters text[] := '{}'::text[];
-andfilters text[] := '{}'::text[];
-output text;
-token_where text;
+    token_id text;
+    filters text[] := '{}'::text[];
+    prev boolean := TRUE;
+    field text;
+    dir text;
+    sort record;
+    orfilters text[] := '{}'::text[];
+    andfilters text[] := '{}'::text[];
+    output text;
+    token_where text;
 BEGIN
--- If no token provided return NULL
-IF token_rec IS NULL THEN
-    IF NOT (_search ? 'token' AND
-            (
-                (_search->>'token' ILIKE 'prev:%')
-                OR
-                (_search->>'token' ILIKE 'next:%')
-            )
-    ) THEN
-        RETURN NULL;
+    -- If no token provided return NULL
+    IF token_rec IS NULL THEN
+        IF NOT (_search ? 'token' AND
+                (
+                    (_search->>'token' ILIKE 'prev:%')
+                    OR
+                    (_search->>'token' ILIKE 'next:%')
+                )
+        ) THEN
+            RETURN NULL;
+        END IF;
+        prev := (_search->>'token' ILIKE 'prev:%');
+        token_id := substr(_search->>'token', 6);
+        SELECT to_jsonb(items) INTO token_rec FROM items WHERE id=token_id;
     END IF;
-    prev := (_search->>'token' ILIKE 'prev:%');
-    token_id := substr(_search->>'token', 6);
-    SELECT to_jsonb(items) INTO token_rec FROM items WHERE id=token_id;
-END IF;
-RAISE NOTICE 'TOKEN ID: %', token_rec->'id';
+    RAISE NOTICE 'TOKEN ID: %', token_rec->'id';
 
-CREATE TEMP TABLE sorts (
-    _row int GENERATED ALWAYS AS IDENTITY NOT NULL,
-    _field text PRIMARY KEY,
-    _dir text NOT NULL,
-    _val text
-) ON COMMIT DROP;
+    CREATE TEMP TABLE sorts (
+        _row int GENERATED ALWAYS AS IDENTITY NOT NULL,
+        _field text PRIMARY KEY,
+        _dir text NOT NULL,
+        _val text
+    ) ON COMMIT DROP;
 
--- Make sure we only have distinct columns to sort with taking the first one we get
-INSERT INTO sorts (_field, _dir)
-    SELECT
-        (items_path(value->>'field')).path,
-        get_sort_dir(value)
-    FROM
-        jsonb_array_elements(coalesce(_search->'sort','[{"field":"datetime","direction":"desc"}]'))
-ON CONFLICT DO NOTHING
-;
-
--- Get the first sort direction provided. As the id is a primary key, if there are any
--- sorts after id they won't do anything, so make sure that id is the last sort item.
-SELECT _dir INTO dir FROM sorts ORDER BY _row ASC LIMIT 1;
-IF EXISTS (SELECT 1 FROM sorts WHERE _field = 'id') THEN
-    DELETE FROM sorts WHERE _row > (SELECT _row FROM sorts WHERE _field = 'id');
-ELSE
-    INSERT INTO sorts (_field, _dir) VALUES ('id', dir);
-END IF;
-
--- Add value from looked up item to the sorts table
-UPDATE sorts SET _val=quote_literal(token_rec->>_field);
-
--- Check if all sorts are the same direction and use row comparison
--- to filter
-IF (SELECT count(DISTINCT _dir) FROM sorts) = 1 THEN
-    SELECT format(
-            '(%s) %s (%s)',
-            concat_ws(', ', VARIADIC array_agg(quote_ident(_field))),
-            CASE WHEN (prev AND dir = 'ASC') OR (NOT prev AND dir = 'DESC') THEN '<' ELSE '>' END,
-            concat_ws(', ', VARIADIC array_agg(_val))
-    ) INTO output FROM sorts
-    WHERE token_rec ? _field
+    -- Make sure we only have distinct columns to sort with taking the first one we get
+    INSERT INTO sorts (_field, _dir)
+        SELECT
+            (items_path(value->>'field')).path,
+            get_sort_dir(value)
+        FROM
+            jsonb_array_elements(coalesce(_search->'sortby','[{"field":"datetime","direction":"desc"}]'))
+    ON CONFLICT DO NOTHING
     ;
-ELSE
-    FOR sort IN SELECT * FROM sorts ORDER BY _row asc LOOP
-        RAISE NOTICE 'SORT: %', sort;
-        IF sort._row = 1 THEN
-            orfilters := orfilters || format('(%s %s %s)',
-                quote_ident(sort._field),
-                CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
-                sort._val
-            );
-        ELSE
-            orfilters := orfilters || format('(%s AND %s %s %s)',
-                array_to_string(andfilters, ' AND '),
+    RAISE NOTICE 'sorts 1: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
+    -- Get the first sort direction provided. As the id is a primary key, if there are any
+    -- sorts after id they won't do anything, so make sure that id is the last sort item.
+    SELECT _dir INTO dir FROM sorts ORDER BY _row ASC LIMIT 1;
+    IF EXISTS (SELECT 1 FROM sorts WHERE _field = 'id') THEN
+        DELETE FROM sorts WHERE _row > (SELECT _row FROM sorts WHERE _field = 'id' ORDER BY _row ASC);
+    ELSE
+        INSERT INTO sorts (_field, _dir) VALUES ('id', dir);
+    END IF;
+
+    -- Add value from looked up item to the sorts table
+    UPDATE sorts SET _val=quote_literal(token_rec->>_field);
+
+    -- Check if all sorts are the same direction and use row comparison
+    -- to filter
+    RAISE NOTICE 'sorts 2: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
+
+    IF (SELECT count(DISTINCT _dir) FROM sorts) = 1 THEN
+        SELECT format(
+                '(%s) %s (%s)',
+                concat_ws(', ', VARIADIC array_agg(quote_ident(_field))),
+                CASE WHEN (prev AND dir = 'ASC') OR (NOT prev AND dir = 'DESC') THEN '<' ELSE '>' END,
+                concat_ws(', ', VARIADIC array_agg(_val))
+        ) INTO output FROM sorts
+        WHERE token_rec ? _field
+        ;
+    ELSE
+        FOR sort IN SELECT * FROM sorts ORDER BY _row asc LOOP
+            RAISE NOTICE 'SORT: %', sort;
+            IF sort._row = 1 THEN
+                orfilters := orfilters || format('(%s %s %s)',
+                    quote_ident(sort._field),
+                    CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
+                    sort._val
+                );
+            ELSE
+                orfilters := orfilters || format('(%s AND %s %s %s)',
+                    array_to_string(andfilters, ' AND '),
+                    quote_ident(sort._field),
+                    CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
+                    sort._val
+                );
+
+            END IF;
+            andfilters := andfilters || format('%s = %s',
                 quote_ident(sort._field),
-                CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
                 sort._val
             );
-
-        END IF;
-        andfilters := andfilters || format('%s = %s',
-            quote_ident(sort._field),
-            sort._val
-        );
-    END LOOP;
-    output := array_to_string(orfilters, ' OR ');
-END IF;
-DROP TABLE IF EXISTS sorts;
-token_where := concat('(',coalesce(output,'true'),')');
-IF trim(token_where) = '' THEN
-    token_where := NULL;
-END IF;
-RAISE NOTICE 'TOKEN_WHERE: |%|',token_where;
-RETURN token_where;
-END;
+        END LOOP;
+        output := array_to_string(orfilters, ' OR ');
+    END IF;
+    DROP TABLE IF EXISTS sorts;
+    token_where := concat('(',coalesce(output,'true'),')');
+    IF trim(token_where) = '' THEN
+        token_where := NULL;
+    END IF;
+    RAISE NOTICE 'TOKEN_WHERE: |%|',token_where;
+    RETURN token_where;
+    END;
 $$ LANGUAGE PLPGSQL;
 
 CREATE OR REPLACE FUNCTION search_tohash(jsonb) RETURNS jsonb AS $$
diff --git a/test/pgtap.sql b/test/pgtap.sql
index 039dd147..17aa684a 100644
--- a/test/pgtap.sql
+++ b/test/pgtap.sql
@@ -19,7 +19,7 @@ SET SEARCH_PATH TO pgstac, pgtap, public;
 SET CLIENT_MIN_MESSAGES TO 'warning';
 
 -- Plan the tests.
-SELECT plan(75);
+SELECT plan(77);
 --SELECT * FROM no_plan();
 
 -- Run the tests.
diff --git a/test/pgtap/004_search.sql b/test/pgtap/004_search.sql
index 696c73a5..cbd9c62f 100644
--- a/test/pgtap/004_search.sql
+++ b/test/pgtap/004_search.sql
@@ -25,7 +25,7 @@ SELECT results_eq($$ SELECT bbox_geom('[0,1,2,3,4,5]'::jsonb) $$, $$ SELECT '010
 SELECT has_function('pgstac'::name, 'add_filters_to_cql', ARRAY['jsonb']);
 
 SELECT results_eq($$
-    SELECT add_filters_to_cql('{"id":["a","b"]}'::jsonb);
+    SELECT add_filters_to_cql('{"ids":["a","b"]}'::jsonb);
     $$,$$
     SELECT '{"filter":{"and": [{"in": [{"property": "id"}, ["a", "b"]]}]}}'::jsonb;
     $$,
@@ -33,7 +33,7 @@ SELECT results_eq($$
 );
 
 SELECT results_eq($$
-    SELECT add_filters_to_cql('{"id":["a","b"],"filter":{"and":[{"eq":[1,1]}]}}'::jsonb);
+    SELECT add_filters_to_cql('{"ids":["a","b"],"filter":{"and":[{"eq":[1,1]}]}}'::jsonb);
     $$,$$
     SELECT '{"filter":{"and": [{"and": [{"eq": [1, 1]}]}, {"and": [{"in": [{"property": "id"}, ["a", "b"]]}]}]}}'::jsonb;
     $$,
@@ -154,6 +154,23 @@ SELECT results_eq($$
     'Test lt as a filter on a numeric field with order by'
 );
 
+SELECT results_eq($$
+    select s from search('{"ids":["pgstac-test-item-0097"],"fields":{"include":["id"]}}') s;
+    $$,$$
+    select '{"next": null, "prev": null, "type": "FeatureCollection", "context": {"limit": 10, "matched": 1, "returned": 1}, "features": [{"id": "pgstac-test-item-0097"}]}'::jsonb
+    $$,
+    'Test ids search single'
+);
+
+SELECT results_eq($$
+    select s from search('{"ids":["pgstac-test-item-0097","pgstac-test-item-0003"],"fields":{"include":["id"]}}') s;
+    $$,$$
+    select '{"next": null, "prev": null, "type": "FeatureCollection", "context": {"limit": 10, "matched": 2, "returned": 2}, "features": [{"id": "pgstac-test-item-0003"},{"id": "pgstac-test-item-0097"}]}'::jsonb
+    $$,
+    'Test ids search multi'
+);
+
+
 SELECT results_eq($$
     select s from search('{"collections":["pgstac-test-collection"],"fields":{"include":["id"]}, "limit": 1}') s;
     $$,$$

From 02de01cbd0693d4fc7e1057ed5eb68e119866698 Mon Sep 17 00:00:00 2001
From: David Bitner <bitner@dbspatial.com>
Date: Mon, 23 Aug 2021 12:04:30 -0500
Subject: [PATCH 10/10] bump version to 0.3.3

---
 pypgstac/pypgstac/__init__.py                 |    2 +-
 .../migrations/pgstac.0.3.1-0.3.2.sql         |  293 +--
 .../migrations/pgstac.0.3.2-0.3.3.sql         |  361 ++++
 pypgstac/pypgstac/migrations/pgstac.0.3.2.sql |  218 ++-
 pypgstac/pypgstac/migrations/pgstac.0.3.3.sql | 1595 +++++++++++++++++
 pypgstac/pyproject.toml                       |    2 +-
 sql/999_version.sql                           |    2 +-
 7 files changed, 2069 insertions(+), 404 deletions(-)
 create mode 100644 pypgstac/pypgstac/migrations/pgstac.0.3.2-0.3.3.sql
 create mode 100644 pypgstac/pypgstac/migrations/pgstac.0.3.3.sql

diff --git a/pypgstac/pypgstac/__init__.py b/pypgstac/pypgstac/__init__.py
index ed51e038..fbfba061 100644
--- a/pypgstac/pypgstac/__init__.py
+++ b/pypgstac/pypgstac/__init__.py
@@ -1,2 +1,2 @@
 """PyPGStac Version."""
-__version__ = "0.3.2"
+__version__ = "0.3.3"
diff --git a/pypgstac/pypgstac/migrations/pgstac.0.3.1-0.3.2.sql b/pypgstac/pypgstac/migrations/pgstac.0.3.1-0.3.2.sql
index 0c59d0f1..825cdd56 100644
--- a/pypgstac/pypgstac/migrations/pgstac.0.3.1-0.3.2.sql
+++ b/pypgstac/pypgstac/migrations/pgstac.0.3.1-0.3.2.sql
@@ -9,12 +9,12 @@ DECLARE
 newprop jsonb;
 newprops jsonb := '[]'::jsonb;
 BEGIN
-IF j ? 'ids' THEN
+IF j ? 'id' THEN
     newprop := jsonb_build_object(
         'in',
         jsonb_build_array(
             '{"property":"id"}'::jsonb,
-            j->'ids'
+            j->'id'
         )
     );
     newprops := jsonb_insert(newprops, '{1}', newprop);
@@ -61,7 +61,7 @@ IF newprops IS NOT NULL AND jsonb_array_length(newprops) > 0 THEN
         j,
         '{filter}',
         cql_and_append(j, jsonb_build_object('and', newprops))
-    ) - '{ids,collections,datetime,bbox,intersects}'::text[];
+    ) - '{id,collections,datetime,bbox,intersects}'::text[];
 END IF;
 
 return j;
@@ -69,293 +69,6 @@ END;
 $function$
 ;
 
-CREATE OR REPLACE FUNCTION pgstac.get_token_filter(_search jsonb DEFAULT '{}'::jsonb, token_rec jsonb DEFAULT NULL::jsonb)
- RETURNS text
- LANGUAGE plpgsql
-AS $function$
-DECLARE
-    token_id text;
-    filters text[] := '{}'::text[];
-    prev boolean := TRUE;
-    field text;
-    dir text;
-    sort record;
-    orfilters text[] := '{}'::text[];
-    andfilters text[] := '{}'::text[];
-    output text;
-    token_where text;
-BEGIN
-    -- If no token provided return NULL
-    IF token_rec IS NULL THEN
-        IF NOT (_search ? 'token' AND
-                (
-                    (_search->>'token' ILIKE 'prev:%')
-                    OR
-                    (_search->>'token' ILIKE 'next:%')
-                )
-        ) THEN
-            RETURN NULL;
-        END IF;
-        prev := (_search->>'token' ILIKE 'prev:%');
-        token_id := substr(_search->>'token', 6);
-        SELECT to_jsonb(items) INTO token_rec FROM items WHERE id=token_id;
-    END IF;
-    RAISE NOTICE 'TOKEN ID: %', token_rec->'id';
-
-    CREATE TEMP TABLE sorts (
-        _row int GENERATED ALWAYS AS IDENTITY NOT NULL,
-        _field text PRIMARY KEY,
-        _dir text NOT NULL,
-        _val text
-    ) ON COMMIT DROP;
-
-    -- Make sure we only have distinct columns to sort with taking the first one we get
-    INSERT INTO sorts (_field, _dir)
-        SELECT
-            (items_path(value->>'field')).path,
-            get_sort_dir(value)
-        FROM
-            jsonb_array_elements(coalesce(_search->'sortby','[{"field":"datetime","direction":"desc"}]'))
-    ON CONFLICT DO NOTHING
-    ;
-    RAISE NOTICE 'sorts 1: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
-    -- Get the first sort direction provided. As the id is a primary key, if there are any
-    -- sorts after id they won't do anything, so make sure that id is the last sort item.
-    SELECT _dir INTO dir FROM sorts ORDER BY _row ASC LIMIT 1;
-    IF EXISTS (SELECT 1 FROM sorts WHERE _field = 'id') THEN
-        DELETE FROM sorts WHERE _row > (SELECT _row FROM sorts WHERE _field = 'id' ORDER BY _row ASC);
-    ELSE
-        INSERT INTO sorts (_field, _dir) VALUES ('id', dir);
-    END IF;
-
-    -- Add value from looked up item to the sorts table
-    UPDATE sorts SET _val=quote_literal(token_rec->>_field);
-
-    -- Check if all sorts are the same direction and use row comparison
-    -- to filter
-    RAISE NOTICE 'sorts 2: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
-
-    IF (SELECT count(DISTINCT _dir) FROM sorts) = 1 THEN
-        SELECT format(
-                '(%s) %s (%s)',
-                concat_ws(', ', VARIADIC array_agg(quote_ident(_field))),
-                CASE WHEN (prev AND dir = 'ASC') OR (NOT prev AND dir = 'DESC') THEN '<' ELSE '>' END,
-                concat_ws(', ', VARIADIC array_agg(_val))
-        ) INTO output FROM sorts
-        WHERE token_rec ? _field
-        ;
-    ELSE
-        FOR sort IN SELECT * FROM sorts ORDER BY _row asc LOOP
-            RAISE NOTICE 'SORT: %', sort;
-            IF sort._row = 1 THEN
-                orfilters := orfilters || format('(%s %s %s)',
-                    quote_ident(sort._field),
-                    CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
-                    sort._val
-                );
-            ELSE
-                orfilters := orfilters || format('(%s AND %s %s %s)',
-                    array_to_string(andfilters, ' AND '),
-                    quote_ident(sort._field),
-                    CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
-                    sort._val
-                );
-
-            END IF;
-            andfilters := andfilters || format('%s = %s',
-                quote_ident(sort._field),
-                sort._val
-            );
-        END LOOP;
-        output := array_to_string(orfilters, ' OR ');
-    END IF;
-    DROP TABLE IF EXISTS sorts;
-    token_where := concat('(',coalesce(output,'true'),')');
-    IF trim(token_where) = '' THEN
-        token_where := NULL;
-    END IF;
-    RAISE NOTICE 'TOKEN_WHERE: |%|',token_where;
-    RETURN token_where;
-    END;
-$function$
-;
-
-CREATE OR REPLACE FUNCTION pgstac.search(_search jsonb DEFAULT '{}'::jsonb)
- RETURNS jsonb
- LANGUAGE plpgsql
- SET jit TO 'off'
-AS $function$
-DECLARE
-    searches searches%ROWTYPE;
-    _where text;
-    token_where text;
-    full_where text;
-    orderby text;
-    query text;
-    token_type text := substr(_search->>'token',1,4);
-    _limit int := coalesce((_search->>'limit')::int, 10);
-    curs refcursor;
-    cntr int := 0;
-    iter_record items%ROWTYPE;
-    first_record items%ROWTYPE;
-    last_record items%ROWTYPE;
-    out_records jsonb := '[]'::jsonb;
-    prev_query text;
-    next text;
-    prev_id text;
-    has_next boolean := false;
-    has_prev boolean := false;
-    prev text;
-    total_count bigint;
-    context jsonb;
-    collection jsonb;
-    includes text[];
-    excludes text[];
-    exit_flag boolean := FALSE;
-    batches int := 0;
-    timer timestamptz := clock_timestamp();
-BEGIN
-searches := search_query(_search);
-_where := searches._where;
-orderby := searches.orderby;
-total_count := coalesce(searches.total_count, searches.estimated_count);
-
-
-IF token_type='prev' THEN
-    token_where := get_token_filter(_search, null::jsonb);
-    orderby := sort_sqlorderby(_search, TRUE);
-END IF;
-IF token_type='next' THEN
-    token_where := get_token_filter(_search, null::jsonb);
-END IF;
-
-full_where := concat_ws(' AND ', _where, token_where);
-RAISE NOTICE 'FULL QUERY % %', full_where, clock_timestamp()-timer;
-timer := clock_timestamp();
-
-FOR query IN SELECT partition_queries(full_where, orderby) LOOP
-    timer := clock_timestamp();
-    query := format('%s LIMIT %L', query, _limit + 1);
-    RAISE NOTICE 'Partition Query: %', query;
-    batches := batches + 1;
-    curs = create_cursor(query);
-    LOOP
-        FETCH curs into iter_record;
-        EXIT WHEN NOT FOUND;
-        cntr := cntr + 1;
-        last_record := iter_record;
-        IF cntr = 1 THEN
-            first_record := last_record;
-        END IF;
-        IF cntr <= _limit THEN
-            out_records := out_records || last_record.content;
-        ELSIF cntr > _limit THEN
-            has_next := true;
-            exit_flag := true;
-            EXIT;
-        END IF;
-    END LOOP;
-    RAISE NOTICE 'Query took %', clock_timestamp()-timer;
-    timer := clock_timestamp();
-    EXIT WHEN exit_flag;
-END LOOP;
-RAISE NOTICE 'Scanned through % partitions.', batches;
-
-
--- Flip things around if this was the result of a prev token query
-IF token_type='prev' THEN
-    out_records := flip_jsonb_array(out_records);
-    first_record := last_record;
-END IF;
-
--- If this query has a token, see if there is data before the first record
-IF _search ? 'token' THEN
-    prev_query := format(
-        'SELECT 1 FROM items WHERE %s LIMIT 1',
-        concat_ws(
-            ' AND ',
-            _where,
-            trim(get_token_filter(_search, to_jsonb(first_record)))
-        )
-    );
-    RAISE NOTICE 'Query to get previous record: % --- %', prev_query, first_record;
-    EXECUTE prev_query INTO has_prev;
-    IF FOUND and has_prev IS NOT NULL THEN
-        RAISE NOTICE 'Query results from prev query: %', has_prev;
-        has_prev := TRUE;
-    END IF;
-END IF;
-has_prev := COALESCE(has_prev, FALSE);
-
-RAISE NOTICE 'token_type: %, has_next: %, has_prev: %', token_type, has_next, has_prev;
-IF has_prev THEN
-    prev := out_records->0->>'id';
-END IF;
-IF has_next OR token_type='prev' THEN
-    next := out_records->-1->>'id';
-END IF;
-
-
--- include/exclude any fields following fields extension
-IF _search ? 'fields' THEN
-    IF _search->'fields' ? 'exclude' THEN
-        excludes=textarr(_search->'fields'->'exclude');
-    END IF;
-    IF _search->'fields' ? 'include' THEN
-        includes=textarr(_search->'fields'->'include');
-        IF array_length(includes, 1)>0 AND NOT 'id' = ANY (includes) THEN
-            includes = includes || '{id}';
-        END IF;
-    END IF;
-    SELECT jsonb_agg(filter_jsonb(row, includes, excludes)) INTO out_records FROM jsonb_array_elements(out_records) row;
-END IF;
-
-context := jsonb_strip_nulls(jsonb_build_object(
-    'limit', _limit,
-    'matched', total_count,
-    'returned', coalesce(jsonb_array_length(out_records), 0)
-));
-
-collection := jsonb_build_object(
-    'type', 'FeatureCollection',
-    'features', coalesce(out_records, '[]'::jsonb),
-    'next', next,
-    'prev', prev,
-    'context', context
-);
-
-RETURN collection;
-END;
-$function$
-;
-
-CREATE OR REPLACE FUNCTION pgstac.sort_sqlorderby(_search jsonb DEFAULT NULL::jsonb, reverse boolean DEFAULT false)
- RETURNS text
- LANGUAGE sql
-AS $function$
-WITH sortby AS (
-    SELECT coalesce(_search->'sortby','[{"field":"datetime", "direction":"desc"}]') as sort
-), withid AS (
-    SELECT CASE
-        WHEN sort @? '$[*] ? (@.field == "id")' THEN sort
-        ELSE sort || '[{"field":"id", "direction":"desc"}]'::jsonb
-        END as sort
-    FROM sortby
-), withid_rows AS (
-    SELECT jsonb_array_elements(sort) as value FROM withid
-),sorts AS (
-    SELECT
-        (items_path(value->>'field')).path as key,
-        parse_sort_dir(value->>'direction', reverse) as dir
-    FROM withid_rows
-)
-SELECT array_to_string(
-    array_agg(concat(key, ' ', dir)),
-    ', '
-) FROM sorts;
-$function$
-;
-
 
 
 INSERT INTO migrations (version) VALUES ('0.3.2');
diff --git a/pypgstac/pypgstac/migrations/pgstac.0.3.2-0.3.3.sql b/pypgstac/pypgstac/migrations/pgstac.0.3.2-0.3.3.sql
new file mode 100644
index 00000000..584c6879
--- /dev/null
+++ b/pypgstac/pypgstac/migrations/pgstac.0.3.2-0.3.3.sql
@@ -0,0 +1,361 @@
+SET SEARCH_PATH to pgstac, public;
+set check_function_bodies = off;
+
+CREATE OR REPLACE FUNCTION pgstac.add_filters_to_cql(j jsonb)
+ RETURNS jsonb
+ LANGUAGE plpgsql
+AS $function$
+DECLARE
+newprop jsonb;
+newprops jsonb := '[]'::jsonb;
+BEGIN
+IF j ? 'ids' THEN
+    newprop := jsonb_build_object(
+        'in',
+        jsonb_build_array(
+            '{"property":"id"}'::jsonb,
+            j->'ids'
+        )
+    );
+    newprops := jsonb_insert(newprops, '{1}', newprop);
+END IF;
+IF j ? 'collections' THEN
+    newprop := jsonb_build_object(
+        'in',
+        jsonb_build_array(
+            '{"property":"collection"}'::jsonb,
+            j->'collections'
+        )
+    );
+    newprops := jsonb_insert(newprops, '{1}', newprop);
+END IF;
+
+IF j ? 'datetime' THEN
+    newprop := format(
+        '{"anyinteracts":[{"property":"datetime"}, %s]}',
+        j->'datetime'
+    );
+    newprops := jsonb_insert(newprops, '{1}', newprop);
+END IF;
+
+IF j ? 'bbox' THEN
+    newprop := format(
+        '{"intersects":[{"property":"geometry"}, %s]}',
+        j->'bbox'
+    );
+    newprops := jsonb_insert(newprops, '{1}', newprop);
+END IF;
+
+IF j ? 'intersects' THEN
+    newprop := format(
+        '{"intersects":[{"property":"geometry"}, %s]}',
+        j->'intersects'
+    );
+    newprops := jsonb_insert(newprops, '{1}', newprop);
+END IF;
+
+RAISE NOTICE 'newprops: %', newprops;
+
+IF newprops IS NOT NULL AND jsonb_array_length(newprops) > 0 THEN
+    return jsonb_set(
+        j,
+        '{filter}',
+        cql_and_append(j, jsonb_build_object('and', newprops))
+    ) - '{ids,collections,datetime,bbox,intersects}'::text[];
+END IF;
+
+return j;
+END;
+$function$
+;
+
+CREATE OR REPLACE FUNCTION pgstac.get_token_filter(_search jsonb DEFAULT '{}'::jsonb, token_rec jsonb DEFAULT NULL::jsonb)
+ RETURNS text
+ LANGUAGE plpgsql
+AS $function$
+DECLARE
+    token_id text;
+    filters text[] := '{}'::text[];
+    prev boolean := TRUE;
+    field text;
+    dir text;
+    sort record;
+    orfilters text[] := '{}'::text[];
+    andfilters text[] := '{}'::text[];
+    output text;
+    token_where text;
+BEGIN
+    -- If no token provided return NULL
+    IF token_rec IS NULL THEN
+        IF NOT (_search ? 'token' AND
+                (
+                    (_search->>'token' ILIKE 'prev:%')
+                    OR
+                    (_search->>'token' ILIKE 'next:%')
+                )
+        ) THEN
+            RETURN NULL;
+        END IF;
+        prev := (_search->>'token' ILIKE 'prev:%');
+        token_id := substr(_search->>'token', 6);
+        SELECT to_jsonb(items) INTO token_rec FROM items WHERE id=token_id;
+    END IF;
+    RAISE NOTICE 'TOKEN ID: %', token_rec->'id';
+
+    CREATE TEMP TABLE sorts (
+        _row int GENERATED ALWAYS AS IDENTITY NOT NULL,
+        _field text PRIMARY KEY,
+        _dir text NOT NULL,
+        _val text
+    ) ON COMMIT DROP;
+
+    -- Make sure we only have distinct columns to sort with taking the first one we get
+    INSERT INTO sorts (_field, _dir)
+        SELECT
+            (items_path(value->>'field')).path,
+            get_sort_dir(value)
+        FROM
+            jsonb_array_elements(coalesce(_search->'sortby','[{"field":"datetime","direction":"desc"}]'))
+    ON CONFLICT DO NOTHING
+    ;
+    RAISE NOTICE 'sorts 1: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
+    -- Get the first sort direction provided. As the id is a primary key, if there are any
+    -- sorts after id they won't do anything, so make sure that id is the last sort item.
+    SELECT _dir INTO dir FROM sorts ORDER BY _row ASC LIMIT 1;
+    IF EXISTS (SELECT 1 FROM sorts WHERE _field = 'id') THEN
+        DELETE FROM sorts WHERE _row > (SELECT _row FROM sorts WHERE _field = 'id' ORDER BY _row ASC);
+    ELSE
+        INSERT INTO sorts (_field, _dir) VALUES ('id', dir);
+    END IF;
+
+    -- Add value from looked up item to the sorts table
+    UPDATE sorts SET _val=quote_literal(token_rec->>_field);
+
+    -- Check if all sorts are the same direction and use row comparison
+    -- to filter
+    RAISE NOTICE 'sorts 2: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
+
+    IF (SELECT count(DISTINCT _dir) FROM sorts) = 1 THEN
+        SELECT format(
+                '(%s) %s (%s)',
+                concat_ws(', ', VARIADIC array_agg(quote_ident(_field))),
+                CASE WHEN (prev AND dir = 'ASC') OR (NOT prev AND dir = 'DESC') THEN '<' ELSE '>' END,
+                concat_ws(', ', VARIADIC array_agg(_val))
+        ) INTO output FROM sorts
+        WHERE token_rec ? _field
+        ;
+    ELSE
+        FOR sort IN SELECT * FROM sorts ORDER BY _row asc LOOP
+            RAISE NOTICE 'SORT: %', sort;
+            IF sort._row = 1 THEN
+                orfilters := orfilters || format('(%s %s %s)',
+                    quote_ident(sort._field),
+                    CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
+                    sort._val
+                );
+            ELSE
+                orfilters := orfilters || format('(%s AND %s %s %s)',
+                    array_to_string(andfilters, ' AND '),
+                    quote_ident(sort._field),
+                    CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
+                    sort._val
+                );
+
+            END IF;
+            andfilters := andfilters || format('%s = %s',
+                quote_ident(sort._field),
+                sort._val
+            );
+        END LOOP;
+        output := array_to_string(orfilters, ' OR ');
+    END IF;
+    DROP TABLE IF EXISTS sorts;
+    token_where := concat('(',coalesce(output,'true'),')');
+    IF trim(token_where) = '' THEN
+        token_where := NULL;
+    END IF;
+    RAISE NOTICE 'TOKEN_WHERE: |%|',token_where;
+    RETURN token_where;
+    END;
+$function$
+;
+
+CREATE OR REPLACE FUNCTION pgstac.search(_search jsonb DEFAULT '{}'::jsonb)
+ RETURNS jsonb
+ LANGUAGE plpgsql
+ SET jit TO 'off'
+AS $function$
+DECLARE
+    searches searches%ROWTYPE;
+    _where text;
+    token_where text;
+    full_where text;
+    orderby text;
+    query text;
+    token_type text := substr(_search->>'token',1,4);
+    _limit int := coalesce((_search->>'limit')::int, 10);
+    curs refcursor;
+    cntr int := 0;
+    iter_record items%ROWTYPE;
+    first_record items%ROWTYPE;
+    last_record items%ROWTYPE;
+    out_records jsonb := '[]'::jsonb;
+    prev_query text;
+    next text;
+    prev_id text;
+    has_next boolean := false;
+    has_prev boolean := false;
+    prev text;
+    total_count bigint;
+    context jsonb;
+    collection jsonb;
+    includes text[];
+    excludes text[];
+    exit_flag boolean := FALSE;
+    batches int := 0;
+    timer timestamptz := clock_timestamp();
+BEGIN
+searches := search_query(_search);
+_where := searches._where;
+orderby := searches.orderby;
+total_count := coalesce(searches.total_count, searches.estimated_count);
+
+
+IF token_type='prev' THEN
+    token_where := get_token_filter(_search, null::jsonb);
+    orderby := sort_sqlorderby(_search, TRUE);
+END IF;
+IF token_type='next' THEN
+    token_where := get_token_filter(_search, null::jsonb);
+END IF;
+
+full_where := concat_ws(' AND ', _where, token_where);
+RAISE NOTICE 'FULL QUERY % %', full_where, clock_timestamp()-timer;
+timer := clock_timestamp();
+
+FOR query IN SELECT partition_queries(full_where, orderby) LOOP
+    timer := clock_timestamp();
+    query := format('%s LIMIT %L', query, _limit + 1);
+    RAISE NOTICE 'Partition Query: %', query;
+    batches := batches + 1;
+    curs = create_cursor(query);
+    LOOP
+        FETCH curs into iter_record;
+        EXIT WHEN NOT FOUND;
+        cntr := cntr + 1;
+        last_record := iter_record;
+        IF cntr = 1 THEN
+            first_record := last_record;
+        END IF;
+        IF cntr <= _limit THEN
+            out_records := out_records || last_record.content;
+        ELSIF cntr > _limit THEN
+            has_next := true;
+            exit_flag := true;
+            EXIT;
+        END IF;
+    END LOOP;
+    RAISE NOTICE 'Query took %', clock_timestamp()-timer;
+    timer := clock_timestamp();
+    EXIT WHEN exit_flag;
+END LOOP;
+RAISE NOTICE 'Scanned through % partitions.', batches;
+
+
+-- Flip things around if this was the result of a prev token query
+IF token_type='prev' THEN
+    out_records := flip_jsonb_array(out_records);
+    first_record := last_record;
+END IF;
+
+-- If this query has a token, see if there is data before the first record
+IF _search ? 'token' THEN
+    prev_query := format(
+        'SELECT 1 FROM items WHERE %s LIMIT 1',
+        concat_ws(
+            ' AND ',
+            _where,
+            trim(get_token_filter(_search, to_jsonb(first_record)))
+        )
+    );
+    RAISE NOTICE 'Query to get previous record: % --- %', prev_query, first_record;
+    EXECUTE prev_query INTO has_prev;
+    IF FOUND and has_prev IS NOT NULL THEN
+        RAISE NOTICE 'Query results from prev query: %', has_prev;
+        has_prev := TRUE;
+    END IF;
+END IF;
+has_prev := COALESCE(has_prev, FALSE);
+
+RAISE NOTICE 'token_type: %, has_next: %, has_prev: %', token_type, has_next, has_prev;
+IF has_prev THEN
+    prev := out_records->0->>'id';
+END IF;
+IF has_next OR token_type='prev' THEN
+    next := out_records->-1->>'id';
+END IF;
+
+
+-- include/exclude any fields following fields extension
+IF _search ? 'fields' THEN
+    IF _search->'fields' ? 'exclude' THEN
+        excludes=textarr(_search->'fields'->'exclude');
+    END IF;
+    IF _search->'fields' ? 'include' THEN
+        includes=textarr(_search->'fields'->'include');
+        IF array_length(includes, 1)>0 AND NOT 'id' = ANY (includes) THEN
+            includes = includes || '{id}';
+        END IF;
+    END IF;
+    SELECT jsonb_agg(filter_jsonb(row, includes, excludes)) INTO out_records FROM jsonb_array_elements(out_records) row;
+END IF;
+
+context := jsonb_strip_nulls(jsonb_build_object(
+    'limit', _limit,
+    'matched', total_count,
+    'returned', coalesce(jsonb_array_length(out_records), 0)
+));
+
+collection := jsonb_build_object(
+    'type', 'FeatureCollection',
+    'features', coalesce(out_records, '[]'::jsonb),
+    'next', next,
+    'prev', prev,
+    'context', context
+);
+
+RETURN collection;
+END;
+$function$
+;
+
+CREATE OR REPLACE FUNCTION pgstac.sort_sqlorderby(_search jsonb DEFAULT NULL::jsonb, reverse boolean DEFAULT false)
+ RETURNS text
+ LANGUAGE sql
+AS $function$
+WITH sortby AS (
+    SELECT coalesce(_search->'sortby','[{"field":"datetime", "direction":"desc"}]') as sort
+), withid AS (
+    SELECT CASE
+        WHEN sort @? '$[*] ? (@.field == "id")' THEN sort
+        ELSE sort || '[{"field":"id", "direction":"desc"}]'::jsonb
+        END as sort
+    FROM sortby
+), withid_rows AS (
+    SELECT jsonb_array_elements(sort) as value FROM withid
+),sorts AS (
+    SELECT
+        (items_path(value->>'field')).path as key,
+        parse_sort_dir(value->>'direction', reverse) as dir
+    FROM withid_rows
+)
+SELECT array_to_string(
+    array_agg(concat(key, ' ', dir)),
+    ', '
+) FROM sorts;
+$function$
+;
+
+
+
+INSERT INTO migrations (version) VALUES ('0.3.3');
diff --git a/pypgstac/pypgstac/migrations/pgstac.0.3.2.sql b/pypgstac/pypgstac/migrations/pgstac.0.3.2.sql
index 2b887455..fb922d3c 100644
--- a/pypgstac/pypgstac/migrations/pgstac.0.3.2.sql
+++ b/pypgstac/pypgstac/migrations/pgstac.0.3.2.sql
@@ -870,12 +870,12 @@ DECLARE
 newprop jsonb;
 newprops jsonb := '[]'::jsonb;
 BEGIN
-IF j ? 'ids' THEN
+IF j ? 'id' THEN
     newprop := jsonb_build_object(
         'in',
         jsonb_build_array(
             '{"property":"id"}'::jsonb,
-            j->'ids'
+            j->'id'
         )
     );
     newprops := jsonb_insert(newprops, '{1}', newprop);
@@ -922,7 +922,7 @@ IF newprops IS NOT NULL AND jsonb_array_length(newprops) > 0 THEN
         j,
         '{filter}',
         cql_and_append(j, jsonb_build_object('and', newprops))
-    ) - '{ids,collections,datetime,bbox,intersects}'::text[];
+    ) - '{id,collections,datetime,bbox,intersects}'::text[];
 END IF;
 
 return j;
@@ -1233,21 +1233,17 @@ CREATE OR REPLACE FUNCTION sort_sqlorderby(
     _search jsonb DEFAULT NULL,
     reverse boolean DEFAULT FALSE
 ) RETURNS text AS $$
-WITH sortby AS (
-    SELECT coalesce(_search->'sortby','[{"field":"datetime", "direction":"desc"}]') as sort
-), withid AS (
-    SELECT CASE
-        WHEN sort @? '$[*] ? (@.field == "id")' THEN sort
-        ELSE sort || '[{"field":"id", "direction":"desc"}]'::jsonb
-        END as sort
-    FROM sortby
-), withid_rows AS (
-    SELECT jsonb_array_elements(sort) as value FROM withid
-),sorts AS (
+WITH sorts AS (
     SELECT
         (items_path(value->>'field')).path as key,
         parse_sort_dir(value->>'direction', reverse) as dir
-    FROM withid_rows
+    FROM jsonb_array_elements(
+        '[]'::jsonb
+        ||
+        coalesce(_search->'sortby','[{"field":"datetime", "direction":"desc"}]')
+        ||
+        '[{"field":"id","direction":"desc"}]'::jsonb
+    )
 )
 SELECT array_to_string(
     array_agg(concat(key, ' ', dir)),
@@ -1262,109 +1258,107 @@ $$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
 
 CREATE OR REPLACE FUNCTION get_token_filter(_search jsonb = '{}'::jsonb, token_rec jsonb DEFAULT NULL) RETURNS text AS $$
 DECLARE
-    token_id text;
-    filters text[] := '{}'::text[];
-    prev boolean := TRUE;
-    field text;
-    dir text;
-    sort record;
-    orfilters text[] := '{}'::text[];
-    andfilters text[] := '{}'::text[];
-    output text;
-    token_where text;
+token_id text;
+filters text[] := '{}'::text[];
+prev boolean := TRUE;
+field text;
+dir text;
+sort record;
+orfilters text[] := '{}'::text[];
+andfilters text[] := '{}'::text[];
+output text;
+token_where text;
 BEGIN
-    -- If no token provided return NULL
-    IF token_rec IS NULL THEN
-        IF NOT (_search ? 'token' AND
-                (
-                    (_search->>'token' ILIKE 'prev:%')
-                    OR
-                    (_search->>'token' ILIKE 'next:%')
-                )
-        ) THEN
-            RETURN NULL;
-        END IF;
-        prev := (_search->>'token' ILIKE 'prev:%');
-        token_id := substr(_search->>'token', 6);
-        SELECT to_jsonb(items) INTO token_rec FROM items WHERE id=token_id;
+-- If no token provided return NULL
+IF token_rec IS NULL THEN
+    IF NOT (_search ? 'token' AND
+            (
+                (_search->>'token' ILIKE 'prev:%')
+                OR
+                (_search->>'token' ILIKE 'next:%')
+            )
+    ) THEN
+        RETURN NULL;
     END IF;
-    RAISE NOTICE 'TOKEN ID: %', token_rec->'id';
+    prev := (_search->>'token' ILIKE 'prev:%');
+    token_id := substr(_search->>'token', 6);
+    SELECT to_jsonb(items) INTO token_rec FROM items WHERE id=token_id;
+END IF;
+RAISE NOTICE 'TOKEN ID: %', token_rec->'id';
 
-    CREATE TEMP TABLE sorts (
-        _row int GENERATED ALWAYS AS IDENTITY NOT NULL,
-        _field text PRIMARY KEY,
-        _dir text NOT NULL,
-        _val text
-    ) ON COMMIT DROP;
+CREATE TEMP TABLE sorts (
+    _row int GENERATED ALWAYS AS IDENTITY NOT NULL,
+    _field text PRIMARY KEY,
+    _dir text NOT NULL,
+    _val text
+) ON COMMIT DROP;
 
-    -- Make sure we only have distinct columns to sort with taking the first one we get
-    INSERT INTO sorts (_field, _dir)
-        SELECT
-            (items_path(value->>'field')).path,
-            get_sort_dir(value)
-        FROM
-            jsonb_array_elements(coalesce(_search->'sortby','[{"field":"datetime","direction":"desc"}]'))
-    ON CONFLICT DO NOTHING
-    ;
-    RAISE NOTICE 'sorts 1: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
-    -- Get the first sort direction provided. As the id is a primary key, if there are any
-    -- sorts after id they won't do anything, so make sure that id is the last sort item.
-    SELECT _dir INTO dir FROM sorts ORDER BY _row ASC LIMIT 1;
-    IF EXISTS (SELECT 1 FROM sorts WHERE _field = 'id') THEN
-        DELETE FROM sorts WHERE _row > (SELECT _row FROM sorts WHERE _field = 'id' ORDER BY _row ASC);
-    ELSE
-        INSERT INTO sorts (_field, _dir) VALUES ('id', dir);
-    END IF;
+-- Make sure we only have distinct columns to sort with taking the first one we get
+INSERT INTO sorts (_field, _dir)
+    SELECT
+        (items_path(value->>'field')).path,
+        get_sort_dir(value)
+    FROM
+        jsonb_array_elements(coalesce(_search->'sort','[{"field":"datetime","direction":"desc"}]'))
+ON CONFLICT DO NOTHING
+;
 
-    -- Add value from looked up item to the sorts table
-    UPDATE sorts SET _val=quote_literal(token_rec->>_field);
-
-    -- Check if all sorts are the same direction and use row comparison
-    -- to filter
-    RAISE NOTICE 'sorts 2: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
-
-    IF (SELECT count(DISTINCT _dir) FROM sorts) = 1 THEN
-        SELECT format(
-                '(%s) %s (%s)',
-                concat_ws(', ', VARIADIC array_agg(quote_ident(_field))),
-                CASE WHEN (prev AND dir = 'ASC') OR (NOT prev AND dir = 'DESC') THEN '<' ELSE '>' END,
-                concat_ws(', ', VARIADIC array_agg(_val))
-        ) INTO output FROM sorts
-        WHERE token_rec ? _field
-        ;
-    ELSE
-        FOR sort IN SELECT * FROM sorts ORDER BY _row asc LOOP
-            RAISE NOTICE 'SORT: %', sort;
-            IF sort._row = 1 THEN
-                orfilters := orfilters || format('(%s %s %s)',
-                    quote_ident(sort._field),
-                    CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
-                    sort._val
-                );
-            ELSE
-                orfilters := orfilters || format('(%s AND %s %s %s)',
-                    array_to_string(andfilters, ' AND '),
-                    quote_ident(sort._field),
-                    CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
-                    sort._val
-                );
-
-            END IF;
-            andfilters := andfilters || format('%s = %s',
+-- Get the first sort direction provided. As the id is a primary key, if there are any
+-- sorts after id they won't do anything, so make sure that id is the last sort item.
+SELECT _dir INTO dir FROM sorts ORDER BY _row ASC LIMIT 1;
+IF EXISTS (SELECT 1 FROM sorts WHERE _field = 'id') THEN
+    DELETE FROM sorts WHERE _row > (SELECT _row FROM sorts WHERE _field = 'id');
+ELSE
+    INSERT INTO sorts (_field, _dir) VALUES ('id', dir);
+END IF;
+
+-- Add value from looked up item to the sorts table
+UPDATE sorts SET _val=quote_literal(token_rec->>_field);
+
+-- Check if all sorts are the same direction and use row comparison
+-- to filter
+IF (SELECT count(DISTINCT _dir) FROM sorts) = 1 THEN
+    SELECT format(
+            '(%s) %s (%s)',
+            concat_ws(', ', VARIADIC array_agg(quote_ident(_field))),
+            CASE WHEN (prev AND dir = 'ASC') OR (NOT prev AND dir = 'DESC') THEN '<' ELSE '>' END,
+            concat_ws(', ', VARIADIC array_agg(_val))
+    ) INTO output FROM sorts
+    WHERE token_rec ? _field
+    ;
+ELSE
+    FOR sort IN SELECT * FROM sorts ORDER BY _row asc LOOP
+        RAISE NOTICE 'SORT: %', sort;
+        IF sort._row = 1 THEN
+            orfilters := orfilters || format('(%s %s %s)',
                 quote_ident(sort._field),
+                CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
                 sort._val
             );
-        END LOOP;
-        output := array_to_string(orfilters, ' OR ');
-    END IF;
-    DROP TABLE IF EXISTS sorts;
-    token_where := concat('(',coalesce(output,'true'),')');
-    IF trim(token_where) = '' THEN
-        token_where := NULL;
-    END IF;
-    RAISE NOTICE 'TOKEN_WHERE: |%|',token_where;
-    RETURN token_where;
-    END;
+        ELSE
+            orfilters := orfilters || format('(%s AND %s %s %s)',
+                array_to_string(andfilters, ' AND '),
+                quote_ident(sort._field),
+                CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
+                sort._val
+            );
+
+        END IF;
+        andfilters := andfilters || format('%s = %s',
+            quote_ident(sort._field),
+            sort._val
+        );
+    END LOOP;
+    output := array_to_string(orfilters, ' OR ');
+END IF;
+DROP TABLE IF EXISTS sorts;
+token_where := concat('(',coalesce(output,'true'),')');
+IF trim(token_where) = '' THEN
+    token_where := NULL;
+END IF;
+RAISE NOTICE 'TOKEN_WHERE: |%|',token_where;
+RETURN token_where;
+END;
 $$ LANGUAGE PLPGSQL;
 
 CREATE OR REPLACE FUNCTION search_tohash(jsonb) RETURNS jsonb AS $$
@@ -1561,6 +1555,7 @@ IF has_next OR token_type='prev' THEN
 END IF;
 
 
+
 -- include/exclude any fields following fields extension
 IF _search ? 'fields' THEN
     IF _search->'fields' ? 'exclude' THEN
@@ -1575,6 +1570,7 @@ IF _search ? 'fields' THEN
     SELECT jsonb_agg(filter_jsonb(row, includes, excludes)) INTO out_records FROM jsonb_array_elements(out_records) row;
 END IF;
 
+
 context := jsonb_strip_nulls(jsonb_build_object(
     'limit', _limit,
     'matched', total_count,
@@ -1583,7 +1579,7 @@ context := jsonb_strip_nulls(jsonb_build_object(
 
 collection := jsonb_build_object(
     'type', 'FeatureCollection',
-    'features', coalesce(out_records, '[]'::jsonb),
+    'features', out_records,
     'next', next,
     'prev', prev,
     'context', context
diff --git a/pypgstac/pypgstac/migrations/pgstac.0.3.3.sql b/pypgstac/pypgstac/migrations/pgstac.0.3.3.sql
new file mode 100644
index 00000000..844ec088
--- /dev/null
+++ b/pypgstac/pypgstac/migrations/pgstac.0.3.3.sql
@@ -0,0 +1,1595 @@
+CREATE EXTENSION IF NOT EXISTS postgis;
+CREATE SCHEMA IF NOT EXISTS pgstac;
+SET SEARCH_PATH TO pgstac, public;
+
+CREATE TABLE migrations (
+  version text,
+  datetime timestamptz DEFAULT now() NOT NULL
+);
+
+CREATE OR REPLACE FUNCTION notice(VARIADIC text[]) RETURNS boolean AS $$
+DECLARE
+debug boolean := current_setting('pgstac.debug', true);
+BEGIN
+    IF debug THEN
+        RAISE NOTICE 'NOTICE FROM FUNC: %  >>>>> %', concat_ws(' | ', $1), clock_timestamp();
+        RETURN TRUE;
+    END IF;
+    RETURN FALSE;
+END;
+$$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION empty_arr(ANYARRAY) RETURNS BOOLEAN AS $$
+SELECT CASE
+  WHEN $1 IS NULL THEN TRUE
+  WHEN cardinality($1)<1 THEN TRUE
+ELSE FALSE
+END;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION array_map_ident(_a text[])
+  RETURNS text[] AS $$
+  SELECT array_agg(quote_ident(v)) FROM unnest(_a) v;
+$$ LANGUAGE sql IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION array_map_literal(_a text[])
+  RETURNS text[] AS $$
+  SELECT array_agg(quote_literal(v)) FROM unnest(_a) v;
+$$ LANGUAGE sql IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION estimated_count(_where text) RETURNS bigint AS $$
+DECLARE
+rec record;
+rows bigint;
+BEGIN
+    FOR rec in EXECUTE format(
+        $q$
+            EXPLAIN SELECT 1 FROM items WHERE %s
+        $q$,
+        _where)
+    LOOP
+        rows := substring(rec."QUERY PLAN" FROM ' rows=([[:digit:]]+)');
+        EXIT WHEN rows IS NOT NULL;
+    END LOOP;
+
+    RETURN rows;
+END;
+$$ LANGUAGE PLPGSQL;
+/* converts a jsonb text array to a pg text[] array */
+CREATE OR REPLACE FUNCTION textarr(_js jsonb)
+  RETURNS text[] AS $$
+  SELECT
+    CASE jsonb_typeof(_js)
+        WHEN 'array' THEN ARRAY(SELECT jsonb_array_elements_text(_js))
+        ELSE ARRAY[_js->>0]
+    END
+;
+$$ LANGUAGE sql IMMUTABLE PARALLEL SAFE;
+
+
+CREATE OR REPLACE FUNCTION jsonb_paths (IN jdata jsonb, OUT path text[], OUT value jsonb) RETURNS
+SETOF RECORD AS $$
+with recursive extract_all as
+(
+    select
+        ARRAY[key]::text[] as path,
+        value
+    FROM jsonb_each(jdata)
+union all
+    select
+        path || coalesce(obj_key, (arr_key- 1)::text),
+        coalesce(obj_value, arr_value)
+    from extract_all
+    left join lateral
+        jsonb_each(case jsonb_typeof(value) when 'object' then value end)
+        as o(obj_key, obj_value)
+        on jsonb_typeof(value) = 'object'
+    left join lateral
+        jsonb_array_elements(case jsonb_typeof(value) when 'array' then value end)
+        with ordinality as a(arr_value, arr_key)
+        on jsonb_typeof(value) = 'array'
+    where obj_key is not null or arr_key is not null
+)
+select *
+from extract_all;
+$$ LANGUAGE SQL;
+
+CREATE OR REPLACE FUNCTION jsonb_obj_paths (IN jdata jsonb, OUT path text[], OUT value jsonb) RETURNS
+SETOF RECORD AS $$
+with recursive extract_all as
+(
+    select
+        ARRAY[key]::text[] as path,
+        value
+    FROM jsonb_each(jdata)
+union all
+    select
+        path || obj_key,
+        obj_value
+    from extract_all
+    left join lateral
+        jsonb_each(case jsonb_typeof(value) when 'object' then value end)
+        as o(obj_key, obj_value)
+        on jsonb_typeof(value) = 'object'
+    where obj_key is not null
+)
+select *
+from extract_all;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION jsonb_val_paths (IN jdata jsonb, OUT path text[], OUT value jsonb) RETURNS
+SETOF RECORD AS $$
+SELECT * FROM jsonb_obj_paths(jdata) WHERE jsonb_typeof(value) not in  ('object','array');
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+
+CREATE OR REPLACE FUNCTION path_includes(IN path text[], IN includes text[]) RETURNS BOOLEAN AS $$
+WITH t AS (SELECT unnest(includes) i)
+SELECT EXISTS (
+    SELECT 1 FROM t WHERE path @> string_to_array(trim(i), '.')
+);
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION path_excludes(IN path text[], IN excludes text[]) RETURNS BOOLEAN AS $$
+WITH t AS (SELECT unnest(excludes) e)
+SELECT NOT EXISTS (
+    SELECT 1 FROM t WHERE path @> string_to_array(trim(e), '.')
+);
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+
+CREATE OR REPLACE FUNCTION jsonb_obj_paths_filtered (
+    IN jdata jsonb,
+    IN includes text[] DEFAULT ARRAY[]::text[],
+    IN excludes text[] DEFAULT ARRAY[]::text[],
+    OUT path text[],
+    OUT value jsonb
+) RETURNS
+SETOF RECORD AS $$
+SELECT path, value
+FROM jsonb_obj_paths(jdata)
+WHERE
+    CASE WHEN cardinality(includes) > 0 THEN path_includes(path, includes) ELSE TRUE END
+    AND
+    path_excludes(path, excludes)
+
+;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION filter_jsonb(
+    IN jdata jsonb,
+    IN includes text[] DEFAULT ARRAY[]::text[],
+    IN excludes text[] DEFAULT ARRAY[]::text[]
+) RETURNS jsonb AS $$
+DECLARE
+rec RECORD;
+outj jsonb := '{}'::jsonb;
+created_paths text[] := '{}'::text[];
+BEGIN
+
+IF empty_arr(includes) AND empty_arr(excludes) THEN
+RAISE NOTICE 'no filter';
+  RETURN jdata;
+END IF;
+FOR rec in
+SELECT * FROM jsonb_obj_paths_filtered(jdata, includes, excludes)
+WHERE jsonb_typeof(value) != 'object'
+LOOP
+    IF array_length(rec.path,1)>1 THEN
+        FOR i IN 1..(array_length(rec.path,1)-1) LOOP
+          IF NOT array_to_string(rec.path[1:i],'.') = ANY (created_paths) THEN
+            outj := jsonb_set(outj, rec.path[1:i],'{}', true);
+            created_paths := created_paths || array_to_string(rec.path[1:i],'.');
+          END IF;
+        END LOOP;
+    END IF;
+    outj := jsonb_set(outj, rec.path, rec.value, true);
+    created_paths := created_paths || array_to_string(rec.path,'.');
+END LOOP;
+RETURN outj;
+END;
+$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION flip_jsonb_array(j jsonb) RETURNS jsonb AS $$
+SELECT jsonb_agg(value) FROM (SELECT value FROM jsonb_array_elements(j) WITH ORDINALITY ORDER BY ordinality DESC) as t;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+/* Functions to create an iterable of cursors over partitions. */
+CREATE OR REPLACE FUNCTION create_cursor(q text) RETURNS refcursor AS $$
+DECLARE
+    curs refcursor;
+BEGIN
+    OPEN curs FOR EXECUTE q;
+    RETURN curs;
+END;
+$$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION partition_queries(
+    IN _where text DEFAULT 'TRUE',
+    IN _orderby text DEFAULT 'datetime DESC, id DESC'
+) RETURNS SETOF text AS $$
+DECLARE
+    partition_query text;
+    query text;
+    p record;
+    cursors refcursor;
+BEGIN
+IF _orderby ILIKE 'datetime d%' THEN
+    partition_query := format($q$
+        SELECT partition, tstzrange
+        FROM items_partitions
+        ORDER BY tstzrange DESC;
+    $q$);
+ELSIF _orderby ILIKE 'datetime a%' THEN
+    partition_query := format($q$
+        SELECT partition, tstzrange
+        FROM items_partitions
+        ORDER BY tstzrange ASC
+        ;
+    $q$);
+ELSE
+    query := format($q$
+        SELECT * FROM items
+        WHERE %s
+        ORDER BY %s
+    $q$, _where, _orderby
+    );
+
+    RETURN NEXT query;
+    RETURN;
+END IF;
+FOR p IN
+    EXECUTE partition_query
+LOOP
+    query := format($q$
+        SELECT * FROM items
+        WHERE datetime >= %L AND datetime < %L AND %s
+        ORDER BY %s
+    $q$, lower(p.tstzrange), upper(p.tstzrange), _where, _orderby
+    );
+    RETURN NEXT query;
+END LOOP;
+RETURN;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+
+CREATE OR REPLACE FUNCTION partition_cursor(
+    IN _where text DEFAULT 'TRUE',
+    IN _orderby text DEFAULT 'datetime DESC, id DESC'
+) RETURNS SETOF refcursor AS $$
+DECLARE
+    partition_query text;
+    query text;
+    p record;
+    cursors refcursor;
+BEGIN
+FOR query IN SELECT * FROM partion_queries(_where, _orderby) LOOP
+    RETURN NEXT create_cursor(query);
+END LOOP;
+RETURN;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+
+CREATE OR REPLACE FUNCTION partition_count(
+    IN _where text DEFAULT 'TRUE'
+) RETURNS bigint AS $$
+DECLARE
+    partition_query text;
+    query text;
+    p record;
+    subtotal bigint;
+    total bigint := 0;
+BEGIN
+partition_query := format($q$
+    SELECT partition, tstzrange
+    FROM items_partitions
+    ORDER BY tstzrange DESC;
+$q$);
+RAISE NOTICE 'Partition Query: %', partition_query;
+FOR p IN
+    EXECUTE partition_query
+LOOP
+    query := format($q$
+        SELECT count(*) FROM items
+        WHERE datetime BETWEEN %L AND %L AND %s
+    $q$, lower(p.tstzrange), upper(p.tstzrange), _where
+    );
+    RAISE NOTICE 'Query %', query;
+    RAISE NOTICE 'Partition %, Count %, Total %',p.partition, subtotal, total;
+    EXECUTE query INTO subtotal;
+    total := subtotal + total;
+END LOOP;
+RETURN total;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+/* looks for a geometry in a stac item first from geometry and falling back to bbox */
+CREATE OR REPLACE FUNCTION stac_geom(value jsonb) RETURNS geometry AS $$
+SELECT
+    CASE
+            WHEN value->>'geometry' IS NOT NULL THEN
+                ST_GeomFromGeoJSON(value->>'geometry')
+            WHEN value->>'bbox' IS NOT NULL THEN
+                ST_MakeEnvelope(
+                    (value->'bbox'->>0)::float,
+                    (value->'bbox'->>1)::float,
+                    (value->'bbox'->>2)::float,
+                    (value->'bbox'->>3)::float,
+                    4326
+                )
+            ELSE NULL
+        END as geometry
+;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION stac_datetime(value jsonb) RETURNS timestamptz AS $$
+SELECT COALESCE(
+    (value->'properties'->>'datetime')::timestamptz,
+    (value->'properties'->>'start_datetime')::timestamptz
+);
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE SET TIMEZONE='UTC';
+
+CREATE OR REPLACE FUNCTION stac_end_datetime(value jsonb) RETURNS timestamptz AS $$
+SELECT COALESCE(
+    (value->'properties'->>'datetime')::timestamptz,
+    (value->'properties'->>'end_datetime')::timestamptz
+);
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE SET TIMEZONE='UTC';
+
+
+CREATE OR REPLACE FUNCTION stac_daterange(value jsonb) RETURNS tstzrange AS $$
+SELECT tstzrange(stac_datetime(value),stac_end_datetime(value));
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE SET TIMEZONE='UTC';
+SET SEARCH_PATH TO pgstac, public;
+
+CREATE TABLE IF NOT EXISTS collections (
+    id VARCHAR GENERATED ALWAYS AS (content->>'id') STORED PRIMARY KEY,
+    content JSONB
+);
+
+CREATE OR REPLACE FUNCTION create_collection(data jsonb) RETURNS VOID AS $$
+    INSERT INTO collections (content)
+    VALUES (data)
+    ;
+$$ LANGUAGE SQL SET SEARCH_PATH TO pgstac, public;
+
+CREATE OR REPLACE FUNCTION update_collection(data jsonb) RETURNS VOID AS $$
+DECLARE
+out collections%ROWTYPE;
+BEGIN
+    UPDATE collections SET content=data WHERE id = data->>'id' RETURNING * INTO STRICT out;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+
+CREATE OR REPLACE FUNCTION upsert_collection(data jsonb) RETURNS VOID AS $$
+    INSERT INTO collections (content)
+    VALUES (data)
+    ON CONFLICT (id) DO
+    UPDATE
+        SET content=EXCLUDED.content
+    ;
+$$ LANGUAGE SQL SET SEARCH_PATH TO pgstac, public;
+
+CREATE OR REPLACE FUNCTION delete_collection(_id text) RETURNS VOID AS $$
+DECLARE
+out collections%ROWTYPE;
+BEGIN
+    DELETE FROM collections WHERE id = _id RETURNING * INTO STRICT out;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+
+
+CREATE OR REPLACE FUNCTION get_collection(id text) RETURNS jsonb AS $$
+SELECT content FROM collections
+WHERE id=$1
+;
+$$ LANGUAGE SQL SET SEARCH_PATH TO pgstac, public;
+
+CREATE OR REPLACE FUNCTION all_collections() RETURNS jsonb AS $$
+SELECT jsonb_agg(content) FROM collections;
+;
+$$ LANGUAGE SQL SET SEARCH_PATH TO pgstac, public;
+SET SEARCH_PATH TO pgstac, public;
+
+CREATE TABLE items (
+    id text NOT NULL,
+    geometry geometry NOT NULL,
+    collection_id text NOT NULL,
+    datetime timestamptz NOT NULL,
+    end_datetime timestamptz NOT NULL,
+    properties jsonb NOT NULL,
+    content JSONB NOT NULL
+)
+PARTITION BY RANGE (datetime)
+;
+
+CREATE OR REPLACE FUNCTION properties_idx (IN content jsonb) RETURNS jsonb AS $$
+    with recursive extract_all as
+    (
+        select
+            ARRAY[key]::text[] as path,
+            ARRAY[key]::text[] as fullpath,
+            value
+        FROM jsonb_each(content->'properties')
+    union all
+        select
+            CASE WHEN obj_key IS NOT NULL THEN path || obj_key ELSE path END,
+            path || coalesce(obj_key, (arr_key- 1)::text),
+            coalesce(obj_value, arr_value)
+        from extract_all
+        left join lateral
+            jsonb_each(case jsonb_typeof(value) when 'object' then value end)
+            as o(obj_key, obj_value)
+            on jsonb_typeof(value) = 'object'
+        left join lateral
+            jsonb_array_elements(case jsonb_typeof(value) when 'array' then value end)
+            with ordinality as a(arr_value, arr_key)
+            on jsonb_typeof(value) = 'array'
+        where obj_key is not null or arr_key is not null
+    )
+    , paths AS (
+    select
+        array_to_string(path, '.') as path,
+        value
+    FROM extract_all
+    WHERE
+        jsonb_typeof(value) NOT IN ('array','object')
+    ), grouped AS (
+    SELECT path, jsonb_agg(distinct value) vals FROM paths group by path
+    ) SELECT coalesce(jsonb_object_agg(path, CASE WHEN jsonb_array_length(vals)=1 THEN vals->0 ELSE vals END) - '{datetime}'::text[], '{}'::jsonb) FROM grouped
+    ;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE SET JIT TO OFF;
+
+CREATE INDEX "datetime_idx" ON items (datetime);
+CREATE INDEX "end_datetime_idx" ON items (end_datetime);
+CREATE INDEX "properties_idx" ON items USING GIN (properties jsonb_path_ops);
+CREATE INDEX "collection_idx" ON items (collection_id);
+CREATE INDEX "geometry_idx" ON items USING GIST (geometry);
+CREATE UNIQUE INDEX "items_id_datetime_idx" ON items (datetime, id);
+
+ALTER TABLE items ADD CONSTRAINT items_collections_fk FOREIGN KEY (collection_id) REFERENCES collections(id) ON DELETE CASCADE DEFERRABLE;
+
+CREATE OR REPLACE FUNCTION analyze_empty_partitions() RETURNS VOID AS $$
+DECLARE
+    p text;
+BEGIN
+    FOR p IN SELECT partition FROM all_items_partitions WHERE est_cnt = 0 LOOP
+        EXECUTE format('ANALYZE %I;', p);
+    END LOOP;
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+CREATE OR REPLACE FUNCTION items_partition_name(timestamptz) RETURNS text AS $$
+    SELECT to_char($1, '"items_p"IYYY"w"IW');
+$$ LANGUAGE SQL;
+
+CREATE OR REPLACE FUNCTION items_partition_exists(text) RETURNS boolean AS $$
+    SELECT EXISTS (SELECT 1 FROM pg_catalog.pg_class WHERE relname=$1);
+$$ LANGUAGE SQL;
+
+CREATE OR REPLACE FUNCTION items_partition_exists(timestamptz) RETURNS boolean AS $$
+    SELECT EXISTS (SELECT 1 FROM pg_catalog.pg_class WHERE relname=items_partition_name($1));
+$$ LANGUAGE SQL;
+
+CREATE OR REPLACE FUNCTION items_partition_create_worker(partition text, partition_start timestamptz, partition_end timestamptz) RETURNS VOID AS $$
+DECLARE
+    err_context text;
+BEGIN
+    EXECUTE format(
+        $f$
+            CREATE TABLE IF NOT EXISTS %1$I PARTITION OF items
+                FOR VALUES FROM (%2$L)  TO (%3$L);
+            CREATE UNIQUE INDEX IF NOT EXISTS %4$I ON %1$I (id);
+        $f$,
+        partition,
+        partition_start,
+        partition_end,
+        concat(partition, '_id_pk')
+    );
+EXCEPTION
+        WHEN duplicate_table THEN
+            RAISE NOTICE 'Partition % already exists.', partition;
+        WHEN others THEN
+            GET STACKED DIAGNOSTICS err_context = PG_EXCEPTION_CONTEXT;
+            RAISE INFO 'Error Name:%',SQLERRM;
+            RAISE INFO 'Error State:%', SQLSTATE;
+            RAISE INFO 'Error Context:%', err_context;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH to pgstac, public;
+
+CREATE OR REPLACE FUNCTION items_partition_create(ts timestamptz) RETURNS text AS $$
+DECLARE
+    partition text := items_partition_name(ts);
+    partition_start timestamptz;
+    partition_end timestamptz;
+BEGIN
+    IF items_partition_exists(partition) THEN
+        RETURN partition;
+    END IF;
+    partition_start := date_trunc('week', ts);
+    partition_end := partition_start + '1 week'::interval;
+    PERFORM items_partition_create_worker(partition, partition_start, partition_end);
+    RAISE NOTICE 'partition: %', partition;
+    RETURN partition;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac, public;
+
+CREATE OR REPLACE FUNCTION items_partition_create(st timestamptz, et timestamptz) RETURNS SETOF text AS $$
+WITH t AS (
+    SELECT
+        generate_series(
+            date_trunc('week',st),
+            date_trunc('week', et),
+            '1 week'::interval
+        ) w
+)
+SELECT items_partition_create(w) FROM t;
+$$ LANGUAGE SQL;
+
+
+CREATE UNLOGGED TABLE items_staging (
+    content JSONB NOT NULL
+);
+
+CREATE OR REPLACE FUNCTION items_staging_insert_triggerfunc() RETURNS TRIGGER AS $$
+DECLARE
+    mindate timestamptz;
+    maxdate timestamptz;
+    partition text;
+BEGIN
+    SELECT min(stac_datetime(content)), max(stac_datetime(content)) INTO mindate, maxdate FROM newdata;
+    PERFORM items_partition_create(mindate, maxdate);
+    INSERT INTO items (id, geometry, collection_id, datetime, end_datetime, properties, content)
+        SELECT
+            content->>'id',
+            stac_geom(content),
+            content->>'collection',
+            stac_datetime(content),
+            stac_end_datetime(content),
+            properties_idx(content),
+            content
+        FROM newdata
+    ;
+    DELETE FROM items_staging;
+    PERFORM analyze_empty_partitions();
+    RETURN NULL;
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+CREATE TRIGGER items_staging_insert_trigger AFTER INSERT ON items_staging REFERENCING NEW TABLE AS newdata
+    FOR EACH STATEMENT EXECUTE PROCEDURE items_staging_insert_triggerfunc();
+
+
+CREATE UNLOGGED TABLE items_staging_ignore (
+    content JSONB NOT NULL
+);
+
+CREATE OR REPLACE FUNCTION items_staging_ignore_insert_triggerfunc() RETURNS TRIGGER AS $$
+DECLARE
+    mindate timestamptz;
+    maxdate timestamptz;
+    partition text;
+BEGIN
+    SELECT min(stac_datetime(content)), max(stac_datetime(content)) INTO mindate, maxdate FROM newdata;
+    PERFORM items_partition_create(mindate, maxdate);
+    INSERT INTO items (id, geometry, collection_id, datetime, end_datetime, properties, content)
+        SELECT
+            content->>'id',
+            stac_geom(content),
+            content->>'collection',
+            stac_datetime(content),
+            stac_end_datetime(content),
+            properties_idx(content),
+            content
+        FROM newdata
+    ON CONFLICT DO NOTHING
+    ;
+    DELETE FROM items_staging_ignore;
+    PERFORM analyze_empty_partitions();
+    RETURN NULL;
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+CREATE TRIGGER items_staging_ignore_insert_trigger AFTER INSERT ON items_staging_ignore REFERENCING NEW TABLE AS newdata
+    FOR EACH STATEMENT EXECUTE PROCEDURE items_staging_ignore_insert_triggerfunc();
+
+CREATE UNLOGGED TABLE items_staging_upsert (
+    content JSONB NOT NULL
+);
+
+CREATE OR REPLACE FUNCTION items_staging_upsert_insert_triggerfunc() RETURNS TRIGGER AS $$
+DECLARE
+    mindate timestamptz;
+    maxdate timestamptz;
+    partition text;
+BEGIN
+    SELECT min(stac_datetime(content)), max(stac_datetime(content)) INTO mindate, maxdate FROM newdata;
+    PERFORM items_partition_create(mindate, maxdate);
+    INSERT INTO items (id, geometry, collection_id, datetime, end_datetime, properties, content)
+        SELECT
+            content->>'id',
+            stac_geom(content),
+            content->>'collection',
+            stac_datetime(content),
+            stac_end_datetime(content),
+            properties_idx(content),
+            content
+        FROM newdata
+    ON CONFLICT (datetime, id) DO UPDATE SET
+        content = EXCLUDED.content
+        WHERE items.content IS DISTINCT FROM EXCLUDED.content
+    ;
+    DELETE FROM items_staging_upsert;
+    PERFORM analyze_empty_partitions();
+    RETURN NULL;
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+CREATE TRIGGER items_staging_upsert_insert_trigger AFTER INSERT ON items_staging_upsert REFERENCING NEW TABLE AS newdata
+    FOR EACH STATEMENT EXECUTE PROCEDURE items_staging_upsert_insert_triggerfunc();
+
+CREATE OR REPLACE FUNCTION items_update_triggerfunc() RETURNS TRIGGER AS $$
+DECLARE
+BEGIN
+    NEW.id := NEW.content->>'id';
+    NEW.datetime := stac_datetime(NEW.content);
+    NEW.end_datetime := stac_end_datetime(NEW.content);
+    NEW.collection_id := NEW.content->>'collection';
+    NEW.geometry := stac_geom(NEW.content);
+    NEW.properties := properties_idx(NEW.content);
+    IF TG_OP = 'UPDATE' AND NEW IS NOT DISTINCT FROM OLD THEN
+        RETURN NULL;
+    END IF;
+    RETURN NEW;
+END;
+$$ LANGUAGE PLPGSQL;
+
+CREATE TRIGGER items_update_trigger BEFORE UPDATE ON items
+    FOR EACH ROW EXECUTE PROCEDURE items_update_triggerfunc();
+
+/*
+View to get a table of available items partitions
+with date ranges
+*/
+CREATE VIEW all_items_partitions AS
+WITH base AS
+(SELECT
+    c.oid::pg_catalog.regclass::text as partition,
+    pg_catalog.pg_get_expr(c.relpartbound, c.oid) as _constraint,
+    regexp_matches(
+        pg_catalog.pg_get_expr(c.relpartbound, c.oid),
+        E'\\(''\([0-9 :+-]*\)''\\).*\\(''\([0-9 :+-]*\)''\\)'
+    ) as t,
+    reltuples::bigint as est_cnt
+FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
+WHERE c.oid = i.inhrelid AND i.inhparent = 'items'::regclass)
+SELECT partition, tstzrange(
+    t[1]::timestamptz,
+    t[2]::timestamptz
+), est_cnt
+FROM base
+ORDER BY 2 desc;
+
+CREATE OR REPLACE VIEW items_partitions AS
+SELECT * FROM all_items_partitions WHERE est_cnt>0;
+
+CREATE OR REPLACE FUNCTION get_item(_id text) RETURNS jsonb AS $$
+    SELECT content FROM items WHERE id=_id;
+$$ LANGUAGE SQL SET SEARCH_PATH TO pgstac,public;
+
+CREATE OR REPLACE FUNCTION delete_item(_id text) RETURNS VOID AS $$
+DECLARE
+out items%ROWTYPE;
+BEGIN
+    DELETE FROM items WHERE id = _id RETURNING * INTO STRICT out;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+
+CREATE OR REPLACE FUNCTION create_item(data jsonb) RETURNS VOID AS $$
+    INSERT INTO items_staging (content) VALUES (data);
+$$ LANGUAGE SQL SET SEARCH_PATH TO pgstac,public;
+
+
+CREATE OR REPLACE FUNCTION update_item(data jsonb) RETURNS VOID AS $$
+DECLARE
+    out items%ROWTYPE;
+BEGIN
+    UPDATE items SET content=data WHERE id = data->>'id' RETURNING * INTO STRICT out;
+END;
+$$ LANGUAGE PLPGSQL SET SEARCH_PATH TO pgstac,public;
+
+CREATE OR REPLACE FUNCTION upsert_item(data jsonb) RETURNS VOID AS $$
+    INSERT INTO items_staging_upsert (content) VALUES (data);
+$$ LANGUAGE SQL SET SEARCH_PATH TO pgstac,public;
+
+
+CREATE OR REPLACE FUNCTION collection_bbox(id text) RETURNS jsonb AS $$
+SELECT (replace(replace(replace(st_extent(geometry)::text,'BOX(','[['),')',']]'),' ',','))::jsonb
+FROM items WHERE collection_id=$1;
+;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE SET SEARCH_PATH TO pgstac, public;
+
+CREATE OR REPLACE FUNCTION collection_temporal_extent(id text) RETURNS jsonb AS $$
+SELECT to_jsonb(array[array[min(datetime)::text, max(datetime)::text]])
+FROM items WHERE collection_id=$1;
+;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE SET SEARCH_PATH TO pgstac, public;
+
+CREATE OR REPLACE FUNCTION update_collection_extents() RETURNS VOID AS $$
+UPDATE collections SET
+    content = content ||
+    jsonb_build_object(
+        'extent', jsonb_build_object(
+            'spatial', jsonb_build_object(
+                'bbox', collection_bbox(collections.id)
+            ),
+            'temporal', jsonb_build_object(
+                'interval', collection_temporal_extent(collections.id)
+            )
+        )
+    )
+;
+$$ LANGUAGE SQL SET SEARCH_PATH TO pgstac, public;
+
+SET SEARCH_PATH TO pgstac, public;
+
+CREATE OR REPLACE FUNCTION items_path(
+    IN dotpath text,
+    OUT field text,
+    OUT path text,
+    OUT path_txt text,
+    OUT jsonpath text,
+    OUT eq text
+) RETURNS RECORD AS $$
+DECLARE
+path_elements text[];
+last_element text;
+BEGIN
+dotpath := replace(trim(dotpath), 'properties.', '');
+
+IF dotpath = '' THEN
+    RETURN;
+END IF;
+
+path_elements := string_to_array(dotpath, '.');
+jsonpath := NULL;
+
+IF path_elements[1] IN ('id','geometry','datetime') THEN
+    field := path_elements[1];
+    path_elements := path_elements[2:];
+ELSIF path_elements[1] = 'collection' THEN
+    field := 'collection_id';
+    path_elements := path_elements[2:];
+ELSIF path_elements[1] IN ('links', 'assets', 'stac_version', 'stac_extensions') THEN
+    field := 'content';
+ELSE
+    field := 'content';
+    path_elements := '{properties}'::text[] || path_elements;
+END IF;
+IF cardinality(path_elements)<1 THEN
+    path := field;
+    path_txt := field;
+    jsonpath := '$';
+    eq := NULL; -- format($F$ %s = %%s $F$, field);
+    RETURN;
+END IF;
+
+
+last_element := path_elements[cardinality(path_elements)];
+path_elements := path_elements[1:cardinality(path_elements)-1];
+jsonpath := concat(array_to_string('{$}'::text[] || array_map_ident(path_elements), '.'), '.', quote_ident(last_element));
+path_elements := array_map_literal(path_elements);
+path     := format($F$ properties->%s $F$, quote_literal(dotpath));
+path_txt := format($F$ properties->>%s $F$, quote_literal(dotpath));
+eq := format($F$ properties @? '$.%s[*] ? (@ == %%s) '$F$, quote_ident(dotpath));
+
+RAISE NOTICE 'ITEMS PATH -- % % % % %', field, path, path_txt, jsonpath, eq;
+RETURN;
+END;
+$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE;
+
+
+CREATE OR REPLACE FUNCTION parse_dtrange(IN _indate jsonb, OUT _tstzrange tstzrange) AS $$
+WITH t AS (
+    SELECT CASE
+        WHEN jsonb_typeof(_indate) = 'array' THEN
+            textarr(_indate)
+        ELSE
+            regexp_split_to_array(
+                btrim(_indate::text,'"'),
+                '/'
+            )
+        END AS arr
+)
+, t1 AS (
+    SELECT
+        CASE
+            WHEN array_upper(arr,1) = 1 OR arr[1] = '..' OR arr[1] IS NULL THEN '-infinity'::timestamptz
+            ELSE arr[1]::timestamptz
+        END AS st,
+        CASE
+            WHEN array_upper(arr,1) = 1 THEN arr[1]::timestamptz
+            WHEN arr[2] = '..' OR arr[2] IS NULL THEN 'infinity'::timestamptz
+            ELSE arr[2]::timestamptz
+        END AS et
+    FROM t
+)
+SELECT
+    tstzrange(st,et)
+FROM t1;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+
+CREATE OR REPLACE FUNCTION bbox_geom(_bbox jsonb) RETURNS geometry AS $$
+SELECT CASE jsonb_array_length(_bbox)
+    WHEN 4 THEN
+        ST_SetSRID(ST_MakeEnvelope(
+            (_bbox->>0)::float,
+            (_bbox->>1)::float,
+            (_bbox->>2)::float,
+            (_bbox->>3)::float
+        ),4326)
+    WHEN 6 THEN
+    ST_SetSRID(ST_3DMakeBox(
+        ST_MakePoint(
+            (_bbox->>0)::float,
+            (_bbox->>1)::float,
+            (_bbox->>2)::float
+        ),
+        ST_MakePoint(
+            (_bbox->>3)::float,
+            (_bbox->>4)::float,
+            (_bbox->>5)::float
+        )
+    ),4326)
+    ELSE null END;
+;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION cql_and_append(existing jsonb, newfilters jsonb) RETURNS jsonb AS $$
+SELECT CASE WHEN existing ? 'filter' AND newfilters IS NOT NULL THEN
+    jsonb_build_object(
+        'and',
+        jsonb_build_array(
+            existing->'filter',
+            newfilters
+        )
+    )
+ELSE
+    newfilters
+END;
+$$ LANGUAGE SQL;
+
+
+-- ADDs base filters (ids, collections, datetime, bbox, intersects) that are
+-- added outside of the filter/query in the stac request
+CREATE OR REPLACE FUNCTION add_filters_to_cql(j jsonb) RETURNS jsonb AS $$
+DECLARE
+newprop jsonb;
+newprops jsonb := '[]'::jsonb;
+BEGIN
+IF j ? 'ids' THEN
+    newprop := jsonb_build_object(
+        'in',
+        jsonb_build_array(
+            '{"property":"id"}'::jsonb,
+            j->'ids'
+        )
+    );
+    newprops := jsonb_insert(newprops, '{1}', newprop);
+END IF;
+IF j ? 'collections' THEN
+    newprop := jsonb_build_object(
+        'in',
+        jsonb_build_array(
+            '{"property":"collection"}'::jsonb,
+            j->'collections'
+        )
+    );
+    newprops := jsonb_insert(newprops, '{1}', newprop);
+END IF;
+
+IF j ? 'datetime' THEN
+    newprop := format(
+        '{"anyinteracts":[{"property":"datetime"}, %s]}',
+        j->'datetime'
+    );
+    newprops := jsonb_insert(newprops, '{1}', newprop);
+END IF;
+
+IF j ? 'bbox' THEN
+    newprop := format(
+        '{"intersects":[{"property":"geometry"}, %s]}',
+        j->'bbox'
+    );
+    newprops := jsonb_insert(newprops, '{1}', newprop);
+END IF;
+
+IF j ? 'intersects' THEN
+    newprop := format(
+        '{"intersects":[{"property":"geometry"}, %s]}',
+        j->'intersects'
+    );
+    newprops := jsonb_insert(newprops, '{1}', newprop);
+END IF;
+
+RAISE NOTICE 'newprops: %', newprops;
+
+IF newprops IS NOT NULL AND jsonb_array_length(newprops) > 0 THEN
+    return jsonb_set(
+        j,
+        '{filter}',
+        cql_and_append(j, jsonb_build_object('and', newprops))
+    ) - '{ids,collections,datetime,bbox,intersects}'::text[];
+END IF;
+
+return j;
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+CREATE OR REPLACE FUNCTION query_to_cqlfilter(j jsonb) RETURNS jsonb AS $$
+-- Translates anything passed in through the deprecated "query" into equivalent CQL
+WITH t AS (
+    SELECT key as property, value as ops
+        FROM jsonb_each(j->'query')
+), t2 AS (
+    SELECT property, (jsonb_each(ops)).*
+        FROM t WHERE jsonb_typeof(ops) = 'object'
+    UNION ALL
+    SELECT property, 'eq', ops
+        FROM t WHERE jsonb_typeof(ops) != 'object'
+), t3 AS (
+SELECT
+    jsonb_strip_nulls(jsonb_build_object(
+        'and',
+        jsonb_agg(
+            jsonb_build_object(
+                key,
+                jsonb_build_array(
+                    jsonb_build_object('property',property),
+                    value
+                )
+            )
+        )
+    )) as qcql FROM t2
+)
+SELECT
+    CASE WHEN qcql IS NOT NULL THEN
+        jsonb_set(j, '{filter}', cql_and_append(j, qcql)) - 'query'
+    ELSE j
+    END
+FROM t3
+;
+$$ LANGUAGE SQL;
+
+
+
+CREATE OR REPLACE FUNCTION temporal_op_query(op text, args jsonb) RETURNS text AS $$
+DECLARE
+ll text := 'datetime';
+lh text := 'end_datetime';
+rrange tstzrange;
+rl text;
+rh text;
+outq text;
+BEGIN
+rrange := parse_dtrange(args->1);
+RAISE NOTICE 'Constructing temporal query OP: %, ARGS: %, RRANGE: %', op, args, rrange;
+op := lower(op);
+rl := format('%L::timestamptz', lower(rrange));
+rh := format('%L::timestamptz', upper(rrange));
+outq := CASE op
+    WHEN 't_before'       THEN 'lh < rl'
+    WHEN 't_after'        THEN 'll > rh'
+    WHEN 't_meets'        THEN 'lh = rl'
+    WHEN 't_metby'        THEN 'll = rh'
+    WHEN 't_overlaps'     THEN 'll < rl AND rl < lh < rh'
+    WHEN 't_overlappedby' THEN 'rl < ll < rh AND lh > rh'
+    WHEN 't_starts'       THEN 'll = rl AND lh < rh'
+    WHEN 't_startedby'    THEN 'll = rl AND lh > rh'
+    WHEN 't_during'       THEN 'll > rl AND lh < rh'
+    WHEN 't_contains'     THEN 'll < rl AND lh > rh'
+    WHEN 't_finishes'     THEN 'll > rl AND lh = rh'
+    WHEN 't_finishedby'   THEN 'll < rl AND lh = rh'
+    WHEN 't_equals'       THEN 'll = rl AND lh = rh'
+    WHEN 't_disjoint'     THEN 'NOT (ll <= rh AND lh >= rl)'
+    WHEN 't_intersects'   THEN 'll <= rh AND lh >= rl'
+    WHEN 'anyinteracts'   THEN 'll <= rh AND lh >= rl'
+END;
+outq := regexp_replace(outq, '\mll\M', ll);
+outq := regexp_replace(outq, '\mlh\M', lh);
+outq := regexp_replace(outq, '\mrl\M', rl);
+outq := regexp_replace(outq, '\mrh\M', rh);
+outq := format('(%s)', outq);
+RETURN outq;
+END;
+$$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION spatial_op_query(op text, args jsonb) RETURNS text AS $$
+DECLARE
+geom text;
+j jsonb := args->1;
+BEGIN
+op := lower(op);
+RAISE NOTICE 'Constructing spatial query OP: %, ARGS: %', op, args;
+IF op NOT IN ('s_equals','s_disjoint','s_touches','s_within','s_overlaps','s_crosses','s_intersects','intersects','s_contains') THEN
+    RAISE EXCEPTION 'Spatial Operator % Not Supported', op;
+END IF;
+op := regexp_replace(op, '^s_', 'st_');
+IF op = 'intersects' THEN
+    op := 'st_intersects';
+END IF;
+-- Convert geometry to WKB string
+IF j ? 'type' AND j ? 'coordinates' THEN
+    geom := st_geomfromgeojson(j)::text;
+ELSIF jsonb_typeof(j) = 'array' THEN
+    geom := bbox_geom(j)::text;
+END IF;
+
+RETURN format('%s(geometry, %L::geometry)', op, geom);
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+/* cql_query_op -- Parses a CQL query operation, recursing when necessary
+     IN jsonb -- a subelement from a valid stac query
+     IN text -- the operator being used on elements passed in
+     RETURNS a SQL fragment to be used in a WHERE clause
+*/
+CREATE OR REPLACE FUNCTION cql_query_op(j jsonb, _op text DEFAULT NULL) RETURNS text AS $$
+DECLARE
+jtype text := jsonb_typeof(j);
+op text := lower(_op);
+ops jsonb :=
+    '{
+        "eq": "%s = %s",
+        "lt": "%s < %s",
+        "lte": "%s <= %s",
+        "gt": "%s > %s",
+        "gte": "%s >= %s",
+        "like": "%s LIKE %s",
+        "+": "%s + %s",
+        "-": "%s - %s",
+        "*": "%s * %s",
+        "/": "%s / %s",
+        "in": "%s = ANY (%s)",
+        "not": "NOT (%s)",
+        "between": "%s BETWEEN %s AND %s",
+        "lower":"lower(%s)"
+    }'::jsonb;
+ret text;
+args text[] := NULL;
+
+BEGIN
+RAISE NOTICE 'j: %, op: %, jtype: %', j, op, jtype;
+
+-- Set Lower Case on Both Arguments When Case Insensitive Flag Set
+IF op in ('eq','lt','lte','gt','gte','like') AND jsonb_typeof(j->2) = 'boolean' THEN
+    IF (j->>2)::boolean THEN
+        RETURN format(concat('(',ops->>op,')'), cql_query_op(jsonb_build_array(j->0), 'lower'), cql_query_op(jsonb_build_array(j->1), 'lower'));
+    END IF;
+END IF;
+
+-- Special Case when comparing a property in a jsonb field to a string or number using eq
+-- Allows to leverage GIN index on jsonb fields
+IF op = 'eq' THEN
+    IF j->0 ? 'property'
+        AND jsonb_typeof(j->1) IN ('number','string')
+        AND (items_path(j->0->>'property')).eq IS NOT NULL
+    THEN
+        RETURN format((items_path(j->0->>'property')).eq, j->1);
+    END IF;
+END IF;
+
+IF op ilike 't_%' or op = 'anyinteracts' THEN
+    RETURN temporal_op_query(op, j);
+END IF;
+
+IF op ilike 's_%' or op = 'intersects' THEN
+    RETURN spatial_op_query(op, j);
+END IF;
+
+
+IF jtype = 'object' THEN
+    RAISE NOTICE 'parsing object';
+    IF j ? 'property' THEN
+        -- Convert the property to be used as an identifier
+        return (items_path(j->>'property')).path_txt;
+    ELSIF _op IS NULL THEN
+        -- Iterate to convert elements in an object where the operator has not been set
+        -- Combining with AND
+        SELECT
+            array_to_string(array_agg(cql_query_op(e.value, e.key)), ' AND ')
+        INTO ret
+        FROM jsonb_each(j) e;
+        RETURN ret;
+    END IF;
+END IF;
+
+IF jtype = 'string' THEN
+    RETURN quote_literal(j->>0);
+END IF;
+
+IF jtype ='number' THEN
+    RETURN (j->>0)::numeric;
+END IF;
+
+IF jtype = 'array' AND op IS NULL THEN
+    RAISE NOTICE 'Parsing array into array arg. j: %', j;
+    SELECT format($f$ '{%s}'::text[] $f$, string_agg(e,',')) INTO ret FROM jsonb_array_elements_text(j) e;
+    RETURN ret;
+END IF;
+
+
+-- If the type of the passed json is an array
+-- Calculate the arguments that will be passed to functions/operators
+IF jtype = 'array' THEN
+    RAISE NOTICE 'Parsing array into args. j: %', j;
+    -- If any argument is numeric, cast any text arguments to numeric
+    IF j @? '$[*] ? (@.type() == "number")' THEN
+        SELECT INTO args
+            array_agg(concat('(',cql_query_op(e),')::numeric'))
+        FROM jsonb_array_elements(j) e;
+    ELSE
+        SELECT INTO args
+            array_agg(cql_query_op(e))
+        FROM jsonb_array_elements(j) e;
+    END IF;
+    --RETURN args;
+END IF;
+RAISE NOTICE 'ARGS after array cleaning: %', args;
+
+IF op IS NULL THEN
+    RETURN args::text[];
+END IF;
+
+IF args IS NULL OR cardinality(args) < 1 THEN
+    RAISE NOTICE 'No Args';
+    RETURN '';
+END IF;
+
+IF op IN ('and','or') THEN
+    SELECT
+        CONCAT(
+            '(',
+            array_to_string(args, UPPER(CONCAT(' ',op,' '))),
+            ')'
+        ) INTO ret
+        FROM jsonb_array_elements(j) e;
+        RETURN ret;
+END IF;
+
+-- If the op is in the ops json then run using the template in the json
+IF ops ? op THEN
+    RAISE NOTICE 'ARGS: % MAPPED: %',args, array_map_literal(args);
+
+    RETURN format(concat('(',ops->>op,')'), VARIADIC args);
+END IF;
+
+RETURN j->>0;
+
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+
+
+CREATE OR REPLACE FUNCTION cql_to_where(_search jsonb = '{}'::jsonb) RETURNS text AS $$
+DECLARE
+search jsonb := _search;
+_where text;
+BEGIN
+RAISE NOTICE 'SEARCH CQL 1: %', search;
+
+-- Convert any old style stac query to cql
+search := query_to_cqlfilter(search);
+
+RAISE NOTICE 'SEARCH CQL 2: %', search;
+
+-- Convert item,collection,datetime,bbox,intersects to cql
+search := add_filters_to_cql(search);
+
+RAISE NOTICE 'SEARCH CQL Final: %', search;
+_where := cql_query_op(search->'filter');
+
+IF trim(_where) = '' THEN
+    _where := NULL;
+END IF;
+_where := coalesce(_where, ' TRUE ');
+RETURN _where;
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+CREATE OR REPLACE FUNCTION parse_sort_dir(_dir text, reverse boolean default false) RETURNS text AS $$
+WITH t AS (
+    SELECT COALESCE(upper(_dir), 'ASC') as d
+) SELECT
+    CASE
+        WHEN NOT reverse THEN d
+        WHEN d = 'ASC' THEN 'DESC'
+        WHEN d = 'DESC' THEN 'ASC'
+    END
+FROM t;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION sort_dir_to_op(_dir text, prev boolean default false) RETURNS text AS $$
+WITH t AS (
+    SELECT COALESCE(upper(_dir), 'ASC') as d
+) SELECT
+    CASE
+        WHEN d = 'ASC' AND prev THEN '<='
+        WHEN d = 'DESC' AND prev THEN '>='
+        WHEN d = 'ASC' THEN '>='
+        WHEN d = 'DESC' THEN '<='
+    END
+FROM t;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION sort_sqlorderby(
+    _search jsonb DEFAULT NULL,
+    reverse boolean DEFAULT FALSE
+) RETURNS text AS $$
+WITH sortby AS (
+    SELECT coalesce(_search->'sortby','[{"field":"datetime", "direction":"desc"}]') as sort
+), withid AS (
+    SELECT CASE
+        WHEN sort @? '$[*] ? (@.field == "id")' THEN sort
+        ELSE sort || '[{"field":"id", "direction":"desc"}]'::jsonb
+        END as sort
+    FROM sortby
+), withid_rows AS (
+    SELECT jsonb_array_elements(sort) as value FROM withid
+),sorts AS (
+    SELECT
+        (items_path(value->>'field')).path as key,
+        parse_sort_dir(value->>'direction', reverse) as dir
+    FROM withid_rows
+)
+SELECT array_to_string(
+    array_agg(concat(key, ' ', dir)),
+    ', '
+) FROM sorts;
+$$ LANGUAGE SQL;
+
+CREATE OR REPLACE FUNCTION get_sort_dir(sort_item jsonb) RETURNS text AS $$
+SELECT CASE WHEN sort_item->>'direction' ILIKE 'desc%' THEN 'DESC' ELSE 'ASC' END;
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+
+CREATE OR REPLACE FUNCTION get_token_filter(_search jsonb = '{}'::jsonb, token_rec jsonb DEFAULT NULL) RETURNS text AS $$
+DECLARE
+    token_id text;
+    filters text[] := '{}'::text[];
+    prev boolean := TRUE;
+    field text;
+    dir text;
+    sort record;
+    orfilters text[] := '{}'::text[];
+    andfilters text[] := '{}'::text[];
+    output text;
+    token_where text;
+BEGIN
+    -- If no token provided return NULL
+    IF token_rec IS NULL THEN
+        IF NOT (_search ? 'token' AND
+                (
+                    (_search->>'token' ILIKE 'prev:%')
+                    OR
+                    (_search->>'token' ILIKE 'next:%')
+                )
+        ) THEN
+            RETURN NULL;
+        END IF;
+        prev := (_search->>'token' ILIKE 'prev:%');
+        token_id := substr(_search->>'token', 6);
+        SELECT to_jsonb(items) INTO token_rec FROM items WHERE id=token_id;
+    END IF;
+    RAISE NOTICE 'TOKEN ID: %', token_rec->'id';
+
+    CREATE TEMP TABLE sorts (
+        _row int GENERATED ALWAYS AS IDENTITY NOT NULL,
+        _field text PRIMARY KEY,
+        _dir text NOT NULL,
+        _val text
+    ) ON COMMIT DROP;
+
+    -- Make sure we only have distinct columns to sort with taking the first one we get
+    INSERT INTO sorts (_field, _dir)
+        SELECT
+            (items_path(value->>'field')).path,
+            get_sort_dir(value)
+        FROM
+            jsonb_array_elements(coalesce(_search->'sortby','[{"field":"datetime","direction":"desc"}]'))
+    ON CONFLICT DO NOTHING
+    ;
+    RAISE NOTICE 'sorts 1: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
+    -- Get the first sort direction provided. As the id is a primary key, if there are any
+    -- sorts after id they won't do anything, so make sure that id is the last sort item.
+    SELECT _dir INTO dir FROM sorts ORDER BY _row ASC LIMIT 1;
+    IF EXISTS (SELECT 1 FROM sorts WHERE _field = 'id') THEN
+        DELETE FROM sorts WHERE _row > (SELECT _row FROM sorts WHERE _field = 'id' ORDER BY _row ASC);
+    ELSE
+        INSERT INTO sorts (_field, _dir) VALUES ('id', dir);
+    END IF;
+
+    -- Add value from looked up item to the sorts table
+    UPDATE sorts SET _val=quote_literal(token_rec->>_field);
+
+    -- Check if all sorts are the same direction and use row comparison
+    -- to filter
+    RAISE NOTICE 'sorts 2: %', (SELECT jsonb_agg(to_json(sorts)) FROM sorts);
+
+    IF (SELECT count(DISTINCT _dir) FROM sorts) = 1 THEN
+        SELECT format(
+                '(%s) %s (%s)',
+                concat_ws(', ', VARIADIC array_agg(quote_ident(_field))),
+                CASE WHEN (prev AND dir = 'ASC') OR (NOT prev AND dir = 'DESC') THEN '<' ELSE '>' END,
+                concat_ws(', ', VARIADIC array_agg(_val))
+        ) INTO output FROM sorts
+        WHERE token_rec ? _field
+        ;
+    ELSE
+        FOR sort IN SELECT * FROM sorts ORDER BY _row asc LOOP
+            RAISE NOTICE 'SORT: %', sort;
+            IF sort._row = 1 THEN
+                orfilters := orfilters || format('(%s %s %s)',
+                    quote_ident(sort._field),
+                    CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
+                    sort._val
+                );
+            ELSE
+                orfilters := orfilters || format('(%s AND %s %s %s)',
+                    array_to_string(andfilters, ' AND '),
+                    quote_ident(sort._field),
+                    CASE WHEN (prev AND sort._dir = 'ASC') OR (NOT prev AND sort._dir = 'DESC') THEN '<' ELSE '>' END,
+                    sort._val
+                );
+
+            END IF;
+            andfilters := andfilters || format('%s = %s',
+                quote_ident(sort._field),
+                sort._val
+            );
+        END LOOP;
+        output := array_to_string(orfilters, ' OR ');
+    END IF;
+    DROP TABLE IF EXISTS sorts;
+    token_where := concat('(',coalesce(output,'true'),')');
+    IF trim(token_where) = '' THEN
+        token_where := NULL;
+    END IF;
+    RAISE NOTICE 'TOKEN_WHERE: |%|',token_where;
+    RETURN token_where;
+    END;
+$$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION search_tohash(jsonb) RETURNS jsonb AS $$
+    SELECT $1 - '{token,limit,context,includes,excludes}'::text[];
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+CREATE OR REPLACE FUNCTION search_hash(jsonb) RETURNS text AS $$
+    SELECT md5(search_tohash($1)::text);
+$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
+
+
+CREATE TABLE IF NOT EXISTS searches(
+    hash text GENERATED ALWAYS AS (search_hash(search)) STORED PRIMARY KEY,
+    search jsonb NOT NULL,
+    _where text,
+    orderby text,
+    lastused timestamptz DEFAULT now(),
+    usecount bigint DEFAULT 0,
+    statslastupdated timestamptz,
+    estimated_count bigint,
+    total_count bigint
+);
+
+CREATE OR REPLACE FUNCTION search_query(_search jsonb = '{}'::jsonb, updatestats boolean DEFAULT false) RETURNS searches AS $$
+DECLARE
+    search searches%ROWTYPE;
+BEGIN
+INSERT INTO searches (search)
+    VALUES (search_tohash(_search))
+    ON CONFLICT DO NOTHING
+    RETURNING * INTO search;
+IF search.hash IS NULL THEN
+    SELECT * INTO search FROM searches WHERE hash=search_hash(_search);
+END IF;
+IF search._where IS NULL THEN
+    search._where := cql_to_where(_search);
+END IF;
+IF search.orderby IS NULL THEN
+    search.orderby := sort_sqlorderby(_search);
+END IF;
+
+IF search.statslastupdated IS NULL OR age(search.statslastupdated) > '1 day'::interval OR (_search ? 'context' AND search.total_count IS NULL) THEN
+    updatestats := TRUE;
+END IF;
+
+IF updatestats THEN
+    -- Get Estimated Stats
+    RAISE NOTICE 'Getting stats for %', search._where;
+    search.estimated_count := estimated_count(search._where);
+    RAISE NOTICE 'Estimated Count: %', search.estimated_count;
+
+    IF _search ? 'context' OR search.estimated_count < 10000 THEN
+        --search.total_count := partition_count(search._where);
+        EXECUTE format(
+            'SELECT count(*) FROM items WHERE %s',
+            search._where
+        ) INTO search.total_count;
+        RAISE NOTICE 'Actual Count: %', search.total_count;
+    ELSE
+        search.total_count := NULL;
+    END IF;
+    search.statslastupdated := now();
+END IF;
+
+search.lastused := now();
+search.usecount := coalesce(search.usecount,0) + 1;
+RAISE NOTICE 'SEARCH: %', search;
+UPDATE searches SET
+    _where = search._where,
+    orderby = search.orderby,
+    lastused = search.lastused,
+    usecount = search.usecount,
+    statslastupdated = search.statslastupdated,
+    estimated_count = search.estimated_count,
+    total_count = search.total_count
+WHERE hash = search.hash
+;
+RETURN search;
+
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+
+CREATE OR REPLACE FUNCTION search(_search jsonb = '{}'::jsonb) RETURNS jsonb AS $$
+DECLARE
+    searches searches%ROWTYPE;
+    _where text;
+    token_where text;
+    full_where text;
+    orderby text;
+    query text;
+    token_type text := substr(_search->>'token',1,4);
+    _limit int := coalesce((_search->>'limit')::int, 10);
+    curs refcursor;
+    cntr int := 0;
+    iter_record items%ROWTYPE;
+    first_record items%ROWTYPE;
+    last_record items%ROWTYPE;
+    out_records jsonb := '[]'::jsonb;
+    prev_query text;
+    next text;
+    prev_id text;
+    has_next boolean := false;
+    has_prev boolean := false;
+    prev text;
+    total_count bigint;
+    context jsonb;
+    collection jsonb;
+    includes text[];
+    excludes text[];
+    exit_flag boolean := FALSE;
+    batches int := 0;
+    timer timestamptz := clock_timestamp();
+BEGIN
+searches := search_query(_search);
+_where := searches._where;
+orderby := searches.orderby;
+total_count := coalesce(searches.total_count, searches.estimated_count);
+
+
+IF token_type='prev' THEN
+    token_where := get_token_filter(_search, null::jsonb);
+    orderby := sort_sqlorderby(_search, TRUE);
+END IF;
+IF token_type='next' THEN
+    token_where := get_token_filter(_search, null::jsonb);
+END IF;
+
+full_where := concat_ws(' AND ', _where, token_where);
+RAISE NOTICE 'FULL QUERY % %', full_where, clock_timestamp()-timer;
+timer := clock_timestamp();
+
+FOR query IN SELECT partition_queries(full_where, orderby) LOOP
+    timer := clock_timestamp();
+    query := format('%s LIMIT %L', query, _limit + 1);
+    RAISE NOTICE 'Partition Query: %', query;
+    batches := batches + 1;
+    curs = create_cursor(query);
+    LOOP
+        FETCH curs into iter_record;
+        EXIT WHEN NOT FOUND;
+        cntr := cntr + 1;
+        last_record := iter_record;
+        IF cntr = 1 THEN
+            first_record := last_record;
+        END IF;
+        IF cntr <= _limit THEN
+            out_records := out_records || last_record.content;
+        ELSIF cntr > _limit THEN
+            has_next := true;
+            exit_flag := true;
+            EXIT;
+        END IF;
+    END LOOP;
+    RAISE NOTICE 'Query took %', clock_timestamp()-timer;
+    timer := clock_timestamp();
+    EXIT WHEN exit_flag;
+END LOOP;
+RAISE NOTICE 'Scanned through % partitions.', batches;
+
+
+-- Flip things around if this was the result of a prev token query
+IF token_type='prev' THEN
+    out_records := flip_jsonb_array(out_records);
+    first_record := last_record;
+END IF;
+
+-- If this query has a token, see if there is data before the first record
+IF _search ? 'token' THEN
+    prev_query := format(
+        'SELECT 1 FROM items WHERE %s LIMIT 1',
+        concat_ws(
+            ' AND ',
+            _where,
+            trim(get_token_filter(_search, to_jsonb(first_record)))
+        )
+    );
+    RAISE NOTICE 'Query to get previous record: % --- %', prev_query, first_record;
+    EXECUTE prev_query INTO has_prev;
+    IF FOUND and has_prev IS NOT NULL THEN
+        RAISE NOTICE 'Query results from prev query: %', has_prev;
+        has_prev := TRUE;
+    END IF;
+END IF;
+has_prev := COALESCE(has_prev, FALSE);
+
+RAISE NOTICE 'token_type: %, has_next: %, has_prev: %', token_type, has_next, has_prev;
+IF has_prev THEN
+    prev := out_records->0->>'id';
+END IF;
+IF has_next OR token_type='prev' THEN
+    next := out_records->-1->>'id';
+END IF;
+
+
+-- include/exclude any fields following fields extension
+IF _search ? 'fields' THEN
+    IF _search->'fields' ? 'exclude' THEN
+        excludes=textarr(_search->'fields'->'exclude');
+    END IF;
+    IF _search->'fields' ? 'include' THEN
+        includes=textarr(_search->'fields'->'include');
+        IF array_length(includes, 1)>0 AND NOT 'id' = ANY (includes) THEN
+            includes = includes || '{id}';
+        END IF;
+    END IF;
+    SELECT jsonb_agg(filter_jsonb(row, includes, excludes)) INTO out_records FROM jsonb_array_elements(out_records) row;
+END IF;
+
+context := jsonb_strip_nulls(jsonb_build_object(
+    'limit', _limit,
+    'matched', total_count,
+    'returned', coalesce(jsonb_array_length(out_records), 0)
+));
+
+collection := jsonb_build_object(
+    'type', 'FeatureCollection',
+    'features', coalesce(out_records, '[]'::jsonb),
+    'next', next,
+    'prev', prev,
+    'context', context
+);
+
+RETURN collection;
+END;
+$$ LANGUAGE PLPGSQL SET jit TO off;
+INSERT INTO pgstac.migrations (version) VALUES ('0.3.3');
diff --git a/pypgstac/pyproject.toml b/pypgstac/pyproject.toml
index eca5a498..b10d8ba4 100644
--- a/pypgstac/pyproject.toml
+++ b/pypgstac/pyproject.toml
@@ -1,6 +1,6 @@
 [tool.poetry]
 name = "pypgstac"
-version = "0.3.2"
+version = "0.3.3"
 description = ""
 authors = ["David Bitner <bitner@dbspatial.com>"]
 keywords = ["stac", "asyncpg"]
diff --git a/sql/999_version.sql b/sql/999_version.sql
index 351cd7c1..7909e06b 100644
--- a/sql/999_version.sql
+++ b/sql/999_version.sql
@@ -1 +1 @@
-INSERT INTO pgstac.migrations (version) VALUES ('0.3.2');
+INSERT INTO pgstac.migrations (version) VALUES ('0.3.3');