Skip to content

Commit 7c0386f

Browse files
committed
add support for postgrest prepared statements
1 parent 62fdc41 commit 7c0386f

File tree

8 files changed

+107
-26
lines changed

8 files changed

+107
-26
lines changed

README.md

Lines changed: 32 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -9,6 +9,38 @@
99

1010
---
1111

12+
```sql
13+
select
14+
*
15+
from
16+
index_advisor('
17+
select
18+
book.id,
19+
book.title,
20+
publisher.name as publisher_name,
21+
author.name as author_name,
22+
review.body review_body
23+
from
24+
book
25+
join publisher
26+
on book.publisher_id = publisher.id
27+
join author
28+
on book.author_id = author.id
29+
join review
30+
on book.id = review.book_id
31+
where
32+
author.id = $1
33+
and publisher.id = $2
34+
');
35+
36+
startup_cost_before | startup_cost_after | total_cost_before | total_cost_after | index_statements
37+
---------------------+--------------------+-------------------+------------------+----------------------------------------------------------
38+
27.26 | 12.77 | 68.48 | 42.37 | {"CREATE INDEX ON public.book USING btree (author_id)",
39+
"CREATE INDEX ON public.book USING btree (publisher_id)",
40+
"CREATE INDEX ON public.review USING btree (book_id)"}
41+
(1 row)
42+
```
43+
1244

1345
A PostgreSQL extension for recommending indexes to improve query performance.
1446

index_advisor--0.1.0.sql

Lines changed: 25 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1,7 +1,21 @@
1+
create type index_advisor_output as (
2+
index_statements text[],
3+
startup_cost_before jsonb,
4+
startup_cost_after jsonb,
5+
total_cost_before jsonb,
6+
total_cost_after jsonb
7+
);
8+
19
create function index_advisor(
210
query text
311
)
4-
returns table( index_statement text )
12+
returns table (
13+
startup_cost_before jsonb,
14+
startup_cost_after jsonb,
15+
total_cost_before jsonb,
16+
total_cost_after jsonb,
17+
index_statements text[]
18+
)
519
volatile
620
language plpgsql
721
as $$
@@ -21,6 +35,9 @@ begin
2135
raise exception 'query must not contain a semicolon';
2236
end if;
2337

38+
-- Hack to support PostgREST because the prepared statement for args incorrectly defaults to text
39+
query := replace(query, 'WITH pgrst_payload AS (SELECT $1 AS json_data)', 'WITH pgrst_payload AS (SELECT $1::json AS json_data)');
40+
2441
-- Create a prepared statement for the given query
2542
deallocate all;
2643
execute format('prepare %I as %s', prepared_statement_name, query);
@@ -137,7 +154,13 @@ begin
137154
-- Reset prepared statements
138155
deallocate all;
139156

140-
return query select * from unnest(statements);
157+
return query values (
158+
(plan_initial -> 0 -> 'Plan' -> 'Startup Cost'),
159+
(plan_final -> 0 -> 'Plan' -> 'Startup Cost'),
160+
(plan_initial -> 0 -> 'Plan' -> 'Total Cost'),
161+
(plan_final -> 0 -> 'Plan' -> 'Total Cost'),
162+
statements::text[]
163+
);
141164

142165
end;
143166
$$;

test/expected/integration.out

Lines changed: 10 additions & 10 deletions
Original file line numberDiff line numberDiff line change
@@ -1,16 +1,16 @@
11
begin;
22
create extension index_advisor cascade;
33
NOTICE: installing required extension "hypopg"
4-
create table public.book(
5-
id int,
6-
name text
7-
);
8-
select index_advisor($$
9-
select * from book where id = $1
10-
$$);
11-
index_advisor
12-
----------------------------------------------
13-
CREATE INDEX ON public.book USING btree (id)
4+
create table public.book(
5+
id int,
6+
name text
7+
);
8+
select index_advisor($$
9+
select * from book where id = $1
10+
$$);
11+
index_advisor
12+
------------------------------------------------------------------------------
13+
(0.00,4.07,25.88,13.54,"{""CREATE INDEX ON public.book USING btree (id)""}")
1414
(1 row)
1515

1616
rollback;

test/expected/multi_index.out

Lines changed: 6 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -22,6 +22,8 @@ NOTICE: installing required extension "hypopg"
2222
body text not null
2323
);
2424
select
25+
*
26+
from
2527
index_advisor('
2628
select
2729
book.id,
@@ -41,11 +43,9 @@ NOTICE: installing required extension "hypopg"
4143
author.id = $1
4244
and publisher.id = $2
4345
');
44-
index_advisor
45-
--------------------------------------------------------
46-
CREATE INDEX ON public.book USING btree (author_id)
47-
CREATE INDEX ON public.book USING btree (publisher_id)
48-
CREATE INDEX ON public.review USING btree (book_id)
49-
(3 rows)
46+
startup_cost_before | startup_cost_after | total_cost_before | total_cost_after | index_statements
47+
---------------------+--------------------+-------------------+------------------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------
48+
27.26 | 12.77 | 68.48 | 42.37 | {"CREATE INDEX ON public.book USING btree (author_id)","CREATE INDEX ON public.book USING btree (publisher_id)","CREATE INDEX ON public.review USING btree (book_id)"}
49+
(1 row)
5050

5151
rollback;

test/expected/postgrest_query.out

Lines changed: 13 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,13 @@
1+
begin;
2+
create extension index_advisor cascade;
3+
NOTICE: installing required extension "hypopg"
4+
create function get_info(x int) returns text language sql as $$ select 'foo' $$;
5+
select index_advisor($$
6+
WITH pgrst_source AS (WITH pgrst_payload AS (SELECT $1 AS json_data), pgrst_body AS ( SELECT CASE WHEN json_typeof(json_data) = $4 THEN json_data ELSE json_build_array(json_data) END AS val FROM pgrst_payload), pgrst_args AS ( SELECT * FROM json_to_recordset((SELECT val FROM pgrst_body)) AS _("x" integer) )SELECT "public"."get_info"("x" := (SELECT "x" FROM pgrst_args LIMIT $5)) AS pgrst_scalar) SELECT $6::bigint AS total_result_set, pg_catalog.count(_postgrest_t) AS page_total, coalesce((json_agg(_postgrest_t.pgrst_scalar)->$7)::text, $8) AS body, nullif(current_setting($9, $10), $11) AS response_headers, nullif(current_setting($12, $13), $14) AS response_status FROM (SELECT "get_info".* FROM "pgrst_source" AS "get_info" LIMIT $2 OFFSET $3) _postgrest_t
7+
$$);
8+
index_advisor
9+
--------------------------
10+
(0.07,0.07,0.10,0.10,{})
11+
(1 row)
12+
13+
rollback;

test/sql/integration.sql

Lines changed: 8 additions & 8 deletions
Original file line numberDiff line numberDiff line change
@@ -2,13 +2,13 @@ begin;
22

33
create extension index_advisor cascade;
44

5-
create table public.book(
6-
id int,
7-
name text
8-
);
9-
10-
select index_advisor($$
11-
select * from book where id = $1
12-
$$);
5+
create table public.book(
6+
id int,
7+
name text
8+
);
9+
10+
select index_advisor($$
11+
select * from book where id = $1
12+
$$);
1313

1414
rollback;

test/sql/multi_index.sql

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -27,6 +27,8 @@ begin;
2727
);
2828

2929
select
30+
*
31+
from
3032
index_advisor('
3133
select
3234
book.id,

test/sql/postgrest_query.sql

Lines changed: 11 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,11 @@
1+
begin;
2+
3+
create extension index_advisor cascade;
4+
5+
create function get_info(x int) returns text language sql as $$ select 'foo' $$;
6+
7+
select index_advisor($$
8+
WITH pgrst_source AS (WITH pgrst_payload AS (SELECT $1 AS json_data), pgrst_body AS ( SELECT CASE WHEN json_typeof(json_data) = $4 THEN json_data ELSE json_build_array(json_data) END AS val FROM pgrst_payload), pgrst_args AS ( SELECT * FROM json_to_recordset((SELECT val FROM pgrst_body)) AS _("x" integer) )SELECT "public"."get_info"("x" := (SELECT "x" FROM pgrst_args LIMIT $5)) AS pgrst_scalar) SELECT $6::bigint AS total_result_set, pg_catalog.count(_postgrest_t) AS page_total, coalesce((json_agg(_postgrest_t.pgrst_scalar)->$7)::text, $8) AS body, nullif(current_setting($9, $10), $11) AS response_headers, nullif(current_setting($12, $13), $14) AS response_status FROM (SELECT "get_info".* FROM "pgrst_source" AS "get_info" LIMIT $2 OFFSET $3) _postgrest_t
9+
$$);
10+
11+
rollback;

0 commit comments

Comments
 (0)