├── .github ├── ISSUE_TEMPLATE │ └── bug_report.md └── workflows │ ├── pre-commit.yaml │ └── test.yml ├── .gitignore ├── .pre-commit-config.yaml ├── LICENSE ├── Makefile ├── README.md ├── docs └── img │ └── dashboard.png ├── index_advisor--0.1.0--0.1.1.sql ├── index_advisor--0.1.0.sql ├── index_advisor--0.1.1.sql ├── index_advisor--0.1.2.sql ├── index_advisor--0.2.0.sql ├── index_advisor.control └── test ├── expected ├── disallow_semicolon.out ├── integration.out ├── issue_1.out ├── multi_index.out ├── postgrest_query.out ├── semicolon_in_comment_query.out └── unknown_parameter_type.out └── sql ├── disallow_semicolon.sql ├── integration.sql ├── issue_1.sql ├── multi_index.sql ├── postgrest_query.sql ├── semicolon_in_comment_query.sql └── unknown_parameter_type.sql /.github/ISSUE_TEMPLATE/bug_report.md: -------------------------------------------------------------------------------- 1 | --- 2 | name: Bug report 3 | about: Create a report to help us improve 4 | title: '' 5 | labels: triage-required 6 | assignees: olirice 7 | 8 | --- 9 | 10 | **Describe the bug** 11 | A clear and concise description of what the bug is. 12 | 13 | **To Reproduce** 14 | Steps to reproduce the behavior: 15 | 1. 16 | 2. 17 | 3. 18 | 4. 19 | 20 | **Expected behavior** 21 | A description of what you expected to happen. 22 | 23 | **Screenshots** 24 | If applicable, add screenshots to help explain your problem. 25 | 26 | **Versions:** 27 | - PostgreSQL: [e.g. 15.1] 28 | 29 | **Additional context** 30 | Add any other context about the problem here. 31 | -------------------------------------------------------------------------------- /.github/workflows/pre-commit.yaml: -------------------------------------------------------------------------------- 1 | name: pre-commit 2 | 3 | on: [push] 4 | 5 | jobs: 6 | build: 7 | runs-on: ubuntu-latest 8 | 9 | steps: 10 | - name: checkout 11 | uses: actions/checkout@v2 12 | 13 | - name: set up python 3.10 14 | uses: actions/setup-python@v1 15 | with: 16 | python-version: '3.10' 17 | 18 | - name: install pre-commit 19 | run: | 20 | python -m pip install --upgrade pip 21 | pip install pre-commit 22 | 23 | - name: run pre-commit hooks 24 | run: | 25 | pre-commit run --all-files 26 | -------------------------------------------------------------------------------- /.github/workflows/test.yml: -------------------------------------------------------------------------------- 1 | name: test 2 | 3 | on: 4 | pull_request: 5 | push: { branches: main } 6 | 7 | jobs: 8 | run-test: 9 | runs-on: ubuntu-latest 10 | container: pgxn/pgxn-tools 11 | timeout-minutes: 20 12 | 13 | strategy: 14 | matrix: 15 | pg: [15] 16 | 17 | steps: 18 | - name: Start PostgreSQL ${{ matrix.pg }} 19 | run: pg-start ${{ matrix.pg }} 20 | 21 | - name: Install build-dependencies 22 | run: apt-get install -y liblz4-dev libreadline-dev zlib1g-dev libzstd-dev 23 | 24 | - uses: actions/checkout@v3 25 | 26 | - name: checkout hypopg 27 | uses: actions/checkout@v3 28 | with: 29 | repository: 'HypoPG/hypopg' 30 | ref: 'debian/1.3.1-2' 31 | path: ./hypopg 32 | 33 | - name: Create tests directory 34 | run: sudo -u postgres mkdir /tmp/tests 35 | 36 | - name: Create tests tablespace 37 | run: sudo -u postgres psql -c "CREATE TABLESPACE testts LOCATION '/tmp/tests'" 38 | 39 | - name: Create Database 40 | run: sudo -u postgres psql -c 'CREATE DATABASE contrib_regression;' 41 | 42 | - name: install hypopg 43 | run: | 44 | cd hypopg 45 | sudo make install 46 | cd .. 47 | 48 | - name: Test index-advisor on PG-${{ matrix.pg }} 49 | run: pg-build-test 50 | 51 | - name: Show regression.diffs 52 | if: ${{ failure() }} 53 | run: cat regress/regression.diffs 54 | 55 | - uses: actions/upload-artifact@v3 56 | if: always() 57 | with: 58 | name: regression.out 59 | path: regression.out 60 | retention-days: 7 61 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | results/ 2 | debug/ 3 | __pycache__/ 4 | .python-version 5 | venv/ 6 | site/ 7 | regression.* 8 | .DS_Store 9 | *.egg-info/ 10 | *.json 11 | *.ipynb 12 | *.swp 13 | *.diff 14 | *.rs 15 | .ipynb_checkpoints/* 16 | node_modules/ 17 | -------------------------------------------------------------------------------- /.pre-commit-config.yaml: -------------------------------------------------------------------------------- 1 | repos: 2 | 3 | - repo: https://github.com/Lucas-C/pre-commit-hooks 4 | rev: v1.1.10 5 | hooks: 6 | - id: remove-tabs 7 | name: Tabs-to-Spaces 8 | exclude: ^test/expected 9 | 10 | - repo: https://github.com/pre-commit/pre-commit-hooks 11 | rev: v4.0.1 12 | hooks: 13 | - id: trailing-whitespace 14 | exclude: ^test/expected 15 | - id: end-of-file-fixer 16 | exclude: ^test/expected 17 | - id: check-yaml 18 | - id: check-merge-conflict 19 | - id: check-added-large-files 20 | args: ['--maxkb=500'] 21 | - id: mixed-line-ending 22 | args: ['--fix=lf'] 23 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | The PostgreSQL License 2 | 3 | Copyright (c) 2023, Supabase 4 | 5 | Permission to use, copy, modify, and distribute this software and its documentation for any purpose, without fee, and without a written agreement is hereby granted, provided that the above copyright notice and this paragraph and the following two paragraphs appear in all copies. 6 | 7 | IN NO EVENT SHALL Supabase BE LIABLE TO ANY PARTY FOR DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION, EVEN IF Supabase HAS BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 8 | 9 | Supabase SPECIFICALLY DISCLAIMS ANY WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, AND Supabase HAS NO OBLIGATIONS TO PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS. 10 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = index_advisor 2 | DATA = $(wildcard index_advisor--*.sql) 3 | 4 | TESTS = $(wildcard test/sql/*.sql) 5 | REGRESS = $(patsubst test/sql/%.sql,%,$(TESTS)) 6 | REGRESS_OPTS = --use-existing --inputdir=test 7 | 8 | PG_CONFIG = pg_config 9 | PGXS := $(shell $(PG_CONFIG) --pgxs) 10 | include $(PGXS) 11 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # PostgreSQL Index Advisor 2 | 3 |
9 | 10 | A PostgreSQL extension for recommending indexes to improve query performance. 11 | 12 |  13 | 14 | ## Features 15 | 16 | - Supports generic parameters e.g. `$1`, `$2` 17 | - Supports materialized views 18 | - Identifies tables/columns obfuscaed by views 19 | 20 | 21 | ## API 22 | 23 | #### Description 24 | For a given *query*, searches for a set of SQL DDL `create index` statements that improve the query's execution time; 25 | 26 | #### Signature 27 | ```sql 28 | index_advisor(query text) 29 | returns 30 | table ( 31 | startup_cost_before jsonb, 32 | startup_cost_after jsonb, 33 | total_cost_before jsonb, 34 | total_cost_after jsonb, 35 | index_statements text[], 36 | errors text[] 37 | ) 38 | ``` 39 | 40 | ## Usage 41 | 42 | For a minimal example, the `index_advisor` function can be given a single table query with a filter on an unindexed column. 43 | 44 | ```sql 45 | create extension if not exists index_advisor cascade; 46 | 47 | create table book( 48 | id int primary key, 49 | title text not null 50 | ); 51 | 52 | select 53 | * 54 | from 55 | index_advisor('select book.id from book where title = $1'); 56 | 57 | ``` 58 | 59 | ```markdown 60 | startup_cost_before | startup_cost_after | total_cost_before | total_cost_after | index_statements | errors 61 | ---------------------+--------------------+-------------------+------------------+-----------------------------------------------------+-------- 62 | 0.00 | 1.17 | 25.88 | 6.40 | {"CREATE INDEX ON public.book USING btree (title)"},| {} 63 | 64 | (1 row) 65 | ``` 66 | 67 | More complex queries may generate additional suggested indexes 68 | 69 | ```sql 70 | create extension if not exists index_advisor cascade; 71 | 72 | create table author( 73 | id serial primary key, 74 | name text not null 75 | ); 76 | 77 | create table publisher( 78 | id serial primary key, 79 | name text not null, 80 | corporate_address text 81 | ); 82 | 83 | create table book( 84 | id serial primary key, 85 | author_id int not null references author(id), 86 | publisher_id int not null references publisher(id), 87 | title text 88 | ); 89 | 90 | create table review( 91 | id serial primary key, 92 | book_id int references book(id), 93 | body text not null 94 | ); 95 | 96 | select 97 | * 98 | from 99 | index_advisor(' 100 | select 101 | book.id, 102 | book.title, 103 | publisher.name as publisher_name, 104 | author.name as author_name, 105 | review.body review_body 106 | from 107 | book 108 | join publisher 109 | on book.publisher_id = publisher.id 110 | join author 111 | on book.author_id = author.id 112 | join review 113 | on book.id = review.book_id 114 | where 115 | author.id = $1 116 | and publisher.id = $2 117 | '); 118 | 119 | ``` 120 | 121 | ```markdown 122 | startup_cost_before | startup_cost_after | total_cost_before | total_cost_after | index_statements | errors 123 | ---------------------+--------------------+-------------------+------------------+-----------------------------------------------------------+-------- 124 | 27.26 | 12.77 | 68.48 | 42.37 | {"CREATE INDEX ON public.book USING btree (author_id)", | {} 125 | "CREATE INDEX ON public.book USING btree (publisher_id)", 126 | "CREATE INDEX ON public.review USING btree (book_id)"} 127 | (3 rows) 128 | ``` 129 | 130 | 131 | ## Install 132 | 133 | Requires Postgres with [hypopg](https://github.com/HypoPG/hypopg) installed. 134 | 135 | ```sh 136 | git clone https://github.com/supabase/index_advisor.git 137 | cd index_advisor 138 | sudo make install 139 | ``` 140 | 141 | ## Run Tests 142 | 143 | ```sh 144 | make install; make installcheck 145 | ``` 146 | -------------------------------------------------------------------------------- /docs/img/dashboard.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/supabase/index_advisor/ddb9b4ed17692ef8dbf049fad806426a851a3079/docs/img/dashboard.png -------------------------------------------------------------------------------- /index_advisor--0.1.0--0.1.1.sql: -------------------------------------------------------------------------------- 1 | drop type index_advisor_output; 2 | 3 | create or replace function index_advisor( 4 | query text 5 | ) 6 | returns table ( 7 | startup_cost_before jsonb, 8 | startup_cost_after jsonb, 9 | total_cost_before jsonb, 10 | total_cost_after jsonb, 11 | index_statements text[] 12 | ) 13 | volatile 14 | language plpgsql 15 | as $$ 16 | declare 17 | n_args int; 18 | prepared_statement_name text = 'index_advisor_working_statement'; 19 | hypopg_schema_name text = (select extnamespace::regnamespace::text from pg_extension where extname = 'hypopg'); 20 | explain_plan_statement text; 21 | rec record; 22 | plan_initial jsonb; 23 | plan_final jsonb; 24 | statements text[] = '{}'; 25 | begin 26 | 27 | -- Disallow multiple statements 28 | if query ilike '%;%' then 29 | raise exception 'query must not contain a semicolon'; 30 | end if; 31 | 32 | -- Hack to support PostgREST because the prepared statement for args incorrectly defaults to text 33 | query := replace(query, 'WITH pgrst_payload AS (SELECT $1 AS json_data)', 'WITH pgrst_payload AS (SELECT $1::json AS json_data)'); 34 | 35 | -- Create a prepared statement for the given query 36 | deallocate all; 37 | execute format('prepare %I as %s', prepared_statement_name, query); 38 | 39 | -- Detect how many arguments are present in the prepared statement 40 | n_args = ( 41 | select 42 | coalesce(array_length(parameter_types, 1), 0) 43 | from 44 | pg_prepared_statements 45 | where 46 | name = prepared_statement_name 47 | limit 48 | 1 49 | ); 50 | 51 | -- Create a SQL statement that can be executed to collect the explain plan 52 | explain_plan_statement = format( 53 | 'set local plan_cache_mode = force_generic_plan; explain (format json) execute %I%s', 54 | --'explain (format json) execute %I%s', 55 | prepared_statement_name, 56 | case 57 | when n_args = 0 then '' 58 | else format( 59 | '(%s)', array_to_string(array_fill('null'::text, array[n_args]), ',') 60 | ) 61 | end 62 | ); 63 | 64 | -- Store the query plan before any new indexes 65 | execute explain_plan_statement into plan_initial; 66 | 67 | -- Create possible indexes 68 | for rec in ( 69 | with extension_regclass as ( 70 | select 71 | distinct objid as oid 72 | from 73 | pg_depend 74 | where 75 | deptype = 'e' 76 | ) 77 | select 78 | pc.relnamespace::regnamespace::text as schema_name, 79 | pc.relname as table_name, 80 | pa.attname as column_name, 81 | format( 82 | 'select %I.hypopg_create_index($i$create index on %I.%I(%I)$i$)', 83 | hypopg_schema_name, 84 | pc.relnamespace::regnamespace::text, 85 | pc.relname, 86 | pa.attname 87 | ) hypopg_statement 88 | from 89 | pg_catalog.pg_class pc 90 | join pg_catalog.pg_attribute pa 91 | on pc.oid = pa.attrelid 92 | left join extension_regclass er 93 | on pc.oid = er.oid 94 | left join pg_index pi 95 | on pc.oid = pi.indrelid 96 | and (select array_agg(x) from unnest(pi.indkey) v(x)) = array[pa.attnum] 97 | and pi.indexprs is null -- ignore expression indexes 98 | and pi.indpred is null -- ignore partial indexes 99 | where 100 | pc.relnamespace::regnamespace::text not in ( -- ignore schema list 101 | 'pg_catalog', 'pg_toast', 'information_schema' 102 | ) 103 | and er.oid is null -- ignore entities owned by extensions 104 | and pc.relkind in ('r', 'm') -- regular tables, and materialized views 105 | and pc.relpersistence = 'p' -- permanent tables (not unlogged or temporary) 106 | and pa.attnum > 0 107 | and not pa.attisdropped 108 | and pi.indrelid is null 109 | and pa.atttypid in (20,16,1082,1184,1114,701,23,21,700,1083,2950,1700,25,18,1042,1043) 110 | ) 111 | loop 112 | -- Create the hypothetical index 113 | execute rec.hypopg_statement; 114 | end loop; 115 | 116 | /* 117 | for rec in select * from hypopg() 118 | loop 119 | raise notice '%', rec; 120 | end loop; 121 | */ 122 | 123 | -- Create a prepared statement for the given query 124 | -- The original prepared statement MUST be dropped because its plan is cached 125 | execute format('deallocate %I', prepared_statement_name); 126 | execute format('prepare %I as %s', prepared_statement_name, query); 127 | 128 | -- Store the query plan after new indexes 129 | execute explain_plan_statement into plan_final; 130 | 131 | --raise notice '%', plan_final; 132 | 133 | -- Idenfity referenced indexes in new plan 134 | execute format( 135 | 'select 136 | coalesce(array_agg(hypopg_get_indexdef(indexrelid) order by indrelid, indkey::text), $i${}$i$::text[]) 137 | from 138 | %I.hypopg() 139 | where 140 | %s ilike ($i$%%$i$ || indexname || $i$%%$i$) 141 | ', 142 | hypopg_schema_name, 143 | quote_literal(plan_final)::text 144 | ) into statements; 145 | 146 | -- Reset all hypothetical indexes 147 | perform hypopg_reset(); 148 | 149 | -- Reset prepared statements 150 | deallocate all; 151 | 152 | return query values ( 153 | (plan_initial -> 0 -> 'Plan' -> 'Startup Cost'), 154 | (plan_final -> 0 -> 'Plan' -> 'Startup Cost'), 155 | (plan_initial -> 0 -> 'Plan' -> 'Total Cost'), 156 | (plan_final -> 0 -> 'Plan' -> 'Total Cost'), 157 | statements::text[] 158 | ); 159 | 160 | end; 161 | $$; 162 | -------------------------------------------------------------------------------- /index_advisor--0.1.0.sql: -------------------------------------------------------------------------------- 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 | 9 | create function index_advisor( 10 | query text 11 | ) 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 | ) 19 | volatile 20 | language plpgsql 21 | as $$ 22 | declare 23 | n_args int; 24 | prepared_statement_name text = 'index_advisor_working_statement'; 25 | hypopg_schema_name text = (select extnamespace::regnamespace::text from pg_extension where extname = 'hypopg'); 26 | explain_plan_statement text; 27 | rec record; 28 | plan_initial jsonb; 29 | plan_final jsonb; 30 | statements text[] = '{}'; 31 | begin 32 | 33 | -- Disallow multiple statements 34 | if query ilike '%;%' then 35 | raise exception 'query must not contain a semicolon'; 36 | end if; 37 | 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 | 41 | -- Create a prepared statement for the given query 42 | deallocate all; 43 | execute format('prepare %I as %s', prepared_statement_name, query); 44 | 45 | -- Detect how many arguments are present in the prepared statement 46 | n_args = ( 47 | select 48 | coalesce(array_length(parameter_types, 1), 0) 49 | from 50 | pg_prepared_statements 51 | where 52 | name = prepared_statement_name 53 | limit 54 | 1 55 | ); 56 | 57 | -- Create a SQL statement that can be executed to collect the explain plan 58 | explain_plan_statement = format( 59 | 'set local plan_cache_mode = force_generic_plan; explain (format json) execute %I%s', 60 | --'explain (format json) execute %I%s', 61 | prepared_statement_name, 62 | case 63 | when n_args = 0 then '' 64 | else format( 65 | '(%s)', array_to_string(array_fill('null'::text, array[n_args]), ',') 66 | ) 67 | end 68 | ); 69 | 70 | -- Store the query plan before any new indexes 71 | execute explain_plan_statement into plan_initial; 72 | 73 | -- Create possible indexes 74 | for rec in ( 75 | with extension_regclass as ( 76 | select 77 | distinct objid as oid 78 | from 79 | pg_depend 80 | where 81 | deptype = 'e' 82 | ) 83 | select 84 | pc.relnamespace::regnamespace::text as schema_name, 85 | pc.relname as table_name, 86 | pa.attname as column_name, 87 | format( 88 | 'select %I.hypopg_create_index($i$create index on %I.%I(%I)$i$)', 89 | hypopg_schema_name, 90 | pc.relnamespace::regnamespace::text, 91 | pc.relname, 92 | pa.attname 93 | ) hypopg_statement 94 | from 95 | pg_catalog.pg_class pc 96 | join pg_catalog.pg_attribute pa 97 | on pc.oid = pa.attrelid 98 | left join extension_regclass er 99 | on pc.oid = er.oid 100 | left join pg_index pi 101 | on pc.oid = pi.indrelid 102 | and (select array_agg(x) from unnest(pi.indkey) v(x)) = array[pa.attnum] 103 | and pi.indexprs is null -- ignore expression indexes 104 | and pi.indpred is null -- ignore partial indexes 105 | where 106 | pc.relnamespace::regnamespace::text not in ( -- ignore schema list 107 | 'pg_catalog', 'pg_toast', 'information_schema' 108 | ) 109 | and er.oid is null -- ignore entities owned by extensions 110 | and pc.relkind in ('r', 'm') -- regular tables, and materialized views 111 | and pc.relpersistence = 'p' -- permanent tables (not unlogged or temporary) 112 | and pa.attnum > 0 113 | and not pa.attisdropped 114 | and pi.indrelid is null 115 | ) 116 | loop 117 | -- Create the hypothetical index 118 | execute rec.hypopg_statement; 119 | end loop; 120 | 121 | /* 122 | for rec in select * from hypopg() 123 | loop 124 | raise notice '%', rec; 125 | end loop; 126 | */ 127 | 128 | -- Create a prepared statement for the given query 129 | -- The original prepared statement MUST be dropped because its plan is cached 130 | execute format('deallocate %I', prepared_statement_name); 131 | execute format('prepare %I as %s', prepared_statement_name, query); 132 | 133 | -- Store the query plan after new indexes 134 | execute explain_plan_statement into plan_final; 135 | 136 | --raise notice '%', plan_final; 137 | 138 | -- Idenfity referenced indexes in new plan 139 | execute format( 140 | 'select 141 | coalesce(array_agg(hypopg_get_indexdef(indexrelid) order by indrelid, indkey::text), $i${}$i$::text[]) 142 | from 143 | %I.hypopg() 144 | where 145 | %s ilike ($i$%%$i$ || indexname || $i$%%$i$) 146 | ', 147 | hypopg_schema_name, 148 | quote_literal(plan_final)::text 149 | ) into statements; 150 | 151 | -- Reset all hypothetical indexes 152 | perform hypopg_reset(); 153 | 154 | -- Reset prepared statements 155 | deallocate all; 156 | 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 | ); 164 | 165 | end; 166 | $$; 167 | -------------------------------------------------------------------------------- /index_advisor--0.1.1.sql: -------------------------------------------------------------------------------- 1 | create or replace function index_advisor( 2 | query text 3 | ) 4 | returns table ( 5 | startup_cost_before jsonb, 6 | startup_cost_after jsonb, 7 | total_cost_before jsonb, 8 | total_cost_after jsonb, 9 | index_statements text[] 10 | ) 11 | volatile 12 | language plpgsql 13 | as $$ 14 | declare 15 | n_args int; 16 | prepared_statement_name text = 'index_advisor_working_statement'; 17 | hypopg_schema_name text = (select extnamespace::regnamespace::text from pg_extension where extname = 'hypopg'); 18 | explain_plan_statement text; 19 | rec record; 20 | plan_initial jsonb; 21 | plan_final jsonb; 22 | statements text[] = '{}'; 23 | begin 24 | 25 | -- Disallow multiple statements 26 | if query ilike '%;%' then 27 | raise exception 'query must not contain a semicolon'; 28 | end if; 29 | 30 | -- Hack to support PostgREST because the prepared statement for args incorrectly defaults to text 31 | query := replace(query, 'WITH pgrst_payload AS (SELECT $1 AS json_data)', 'WITH pgrst_payload AS (SELECT $1::json AS json_data)'); 32 | 33 | -- Create a prepared statement for the given query 34 | deallocate all; 35 | execute format('prepare %I as %s', prepared_statement_name, query); 36 | 37 | -- Detect how many arguments are present in the prepared statement 38 | n_args = ( 39 | select 40 | coalesce(array_length(parameter_types, 1), 0) 41 | from 42 | pg_prepared_statements 43 | where 44 | name = prepared_statement_name 45 | limit 46 | 1 47 | ); 48 | 49 | -- Create a SQL statement that can be executed to collect the explain plan 50 | explain_plan_statement = format( 51 | 'set local plan_cache_mode = force_generic_plan; explain (format json) execute %I%s', 52 | --'explain (format json) execute %I%s', 53 | prepared_statement_name, 54 | case 55 | when n_args = 0 then '' 56 | else format( 57 | '(%s)', array_to_string(array_fill('null'::text, array[n_args]), ',') 58 | ) 59 | end 60 | ); 61 | 62 | -- Store the query plan before any new indexes 63 | execute explain_plan_statement into plan_initial; 64 | 65 | -- Create possible indexes 66 | for rec in ( 67 | with extension_regclass as ( 68 | select 69 | distinct objid as oid 70 | from 71 | pg_depend 72 | where 73 | deptype = 'e' 74 | ) 75 | select 76 | pc.relnamespace::regnamespace::text as schema_name, 77 | pc.relname as table_name, 78 | pa.attname as column_name, 79 | format( 80 | 'select %I.hypopg_create_index($i$create index on %I.%I(%I)$i$)', 81 | hypopg_schema_name, 82 | pc.relnamespace::regnamespace::text, 83 | pc.relname, 84 | pa.attname 85 | ) hypopg_statement 86 | from 87 | pg_catalog.pg_class pc 88 | join pg_catalog.pg_attribute pa 89 | on pc.oid = pa.attrelid 90 | left join extension_regclass er 91 | on pc.oid = er.oid 92 | left join pg_index pi 93 | on pc.oid = pi.indrelid 94 | and (select array_agg(x) from unnest(pi.indkey) v(x)) = array[pa.attnum] 95 | and pi.indexprs is null -- ignore expression indexes 96 | and pi.indpred is null -- ignore partial indexes 97 | where 98 | pc.relnamespace::regnamespace::text not in ( -- ignore schema list 99 | 'pg_catalog', 'pg_toast', 'information_schema' 100 | ) 101 | and er.oid is null -- ignore entities owned by extensions 102 | and pc.relkind in ('r', 'm') -- regular tables, and materialized views 103 | and pc.relpersistence = 'p' -- permanent tables (not unlogged or temporary) 104 | and pa.attnum > 0 105 | and not pa.attisdropped 106 | and pi.indrelid is null 107 | and pa.atttypid in (20,16,1082,1184,1114,701,23,21,700,1083,2950,1700,25,18,1042,1043) 108 | ) 109 | loop 110 | -- Create the hypothetical index 111 | execute rec.hypopg_statement; 112 | end loop; 113 | 114 | /* 115 | for rec in select * from hypopg() 116 | loop 117 | raise notice '%', rec; 118 | end loop; 119 | */ 120 | 121 | -- Create a prepared statement for the given query 122 | -- The original prepared statement MUST be dropped because its plan is cached 123 | execute format('deallocate %I', prepared_statement_name); 124 | execute format('prepare %I as %s', prepared_statement_name, query); 125 | 126 | -- Store the query plan after new indexes 127 | execute explain_plan_statement into plan_final; 128 | 129 | --raise notice '%', plan_final; 130 | 131 | -- Idenfity referenced indexes in new plan 132 | execute format( 133 | 'select 134 | coalesce(array_agg(hypopg_get_indexdef(indexrelid) order by indrelid, indkey::text), $i${}$i$::text[]) 135 | from 136 | %I.hypopg() 137 | where 138 | %s ilike ($i$%%$i$ || indexname || $i$%%$i$) 139 | ', 140 | hypopg_schema_name, 141 | quote_literal(plan_final)::text 142 | ) into statements; 143 | 144 | -- Reset all hypothetical indexes 145 | perform hypopg_reset(); 146 | 147 | -- Reset prepared statements 148 | deallocate all; 149 | 150 | return query values ( 151 | (plan_initial -> 0 -> 'Plan' -> 'Startup Cost'), 152 | (plan_final -> 0 -> 'Plan' -> 'Startup Cost'), 153 | (plan_initial -> 0 -> 'Plan' -> 'Total Cost'), 154 | (plan_final -> 0 -> 'Plan' -> 'Total Cost'), 155 | statements::text[] 156 | ); 157 | 158 | end; 159 | $$; 160 | -------------------------------------------------------------------------------- /index_advisor--0.1.2.sql: -------------------------------------------------------------------------------- 1 | create or replace function index_advisor( 2 | query text 3 | ) 4 | returns table ( 5 | startup_cost_before jsonb, 6 | startup_cost_after jsonb, 7 | total_cost_before jsonb, 8 | total_cost_after jsonb, 9 | index_statements text[] 10 | ) 11 | volatile 12 | language plpgsql 13 | as $$ 14 | declare 15 | n_args int; 16 | prepared_statement_name text = 'index_advisor_working_statement'; 17 | hypopg_schema_name text = (select extnamespace::regnamespace::text from pg_extension where extname = 'hypopg'); 18 | explain_plan_statement text; 19 | rec record; 20 | plan_initial jsonb; 21 | plan_final jsonb; 22 | statements text[] = '{}'; 23 | begin 24 | 25 | -- Remove comment lines if they contain a semicolon (this is common is queries through supabase.js) 26 | query := trim( 27 | regexp_replace( 28 | regexp_replace( 29 | regexp_replace(query,'\/\*.+\*\/', '', 'g'), 30 | '--[^\r\n]*', ' ', 'g'), 31 | '\s+', ' ', 'g') 32 | ); 33 | 34 | -- Disallow multiple statements 35 | if query ilike '%;%' then 36 | raise exception 'query must not contain a semicolon'; 37 | end if; 38 | 39 | -- Hack to support PostgREST because the prepared statement for args incorrectly defaults to text 40 | query := replace(query, 'WITH pgrst_payload AS (SELECT $1 AS json_data)', 'WITH pgrst_payload AS (SELECT $1::json AS json_data)'); 41 | 42 | -- Create a prepared statement for the given query 43 | deallocate all; 44 | execute format('prepare %I as %s', prepared_statement_name, query); 45 | 46 | -- Detect how many arguments are present in the prepared statement 47 | n_args = ( 48 | select 49 | coalesce(array_length(parameter_types, 1), 0) 50 | from 51 | pg_prepared_statements 52 | where 53 | name = prepared_statement_name 54 | limit 55 | 1 56 | ); 57 | 58 | -- Create a SQL statement that can be executed to collect the explain plan 59 | explain_plan_statement = format( 60 | 'set local plan_cache_mode = force_generic_plan; explain (format json) execute %I%s', 61 | --'explain (format json) execute %I%s', 62 | prepared_statement_name, 63 | case 64 | when n_args = 0 then '' 65 | else format( 66 | '(%s)', array_to_string(array_fill('null'::text, array[n_args]), ',') 67 | ) 68 | end 69 | ); 70 | 71 | -- Store the query plan before any new indexes 72 | execute explain_plan_statement into plan_initial; 73 | 74 | -- Create possible indexes 75 | for rec in ( 76 | with extension_regclass as ( 77 | select 78 | distinct objid as oid 79 | from 80 | pg_depend 81 | where 82 | deptype = 'e' 83 | ) 84 | select 85 | pc.relnamespace::regnamespace::text as schema_name, 86 | pc.relname as table_name, 87 | pa.attname as column_name, 88 | format( 89 | 'select %I.hypopg_create_index($i$create index on %I.%I(%I)$i$)', 90 | hypopg_schema_name, 91 | pc.relnamespace::regnamespace::text, 92 | pc.relname, 93 | pa.attname 94 | ) hypopg_statement 95 | from 96 | pg_catalog.pg_class pc 97 | join pg_catalog.pg_attribute pa 98 | on pc.oid = pa.attrelid 99 | left join extension_regclass er 100 | on pc.oid = er.oid 101 | left join pg_index pi 102 | on pc.oid = pi.indrelid 103 | and (select array_agg(x) from unnest(pi.indkey) v(x)) = array[pa.attnum] 104 | and pi.indexprs is null -- ignore expression indexes 105 | and pi.indpred is null -- ignore partial indexes 106 | where 107 | pc.relnamespace::regnamespace::text not in ( -- ignore schema list 108 | 'pg_catalog', 'pg_toast', 'information_schema' 109 | ) 110 | and er.oid is null -- ignore entities owned by extensions 111 | and pc.relkind in ('r', 'm') -- regular tables, and materialized views 112 | and pc.relpersistence = 'p' -- permanent tables (not unlogged or temporary) 113 | and pa.attnum > 0 114 | and not pa.attisdropped 115 | and pi.indrelid is null 116 | and pa.atttypid in (20,16,1082,1184,1114,701,23,21,700,1083,2950,1700,25,18,1042,1043) 117 | ) 118 | loop 119 | -- Create the hypothetical index 120 | execute rec.hypopg_statement; 121 | end loop; 122 | 123 | /* 124 | for rec in select * from hypopg() 125 | loop 126 | raise notice '%', rec; 127 | end loop; 128 | */ 129 | 130 | -- Create a prepared statement for the given query 131 | -- The original prepared statement MUST be dropped because its plan is cached 132 | execute format('deallocate %I', prepared_statement_name); 133 | execute format('prepare %I as %s', prepared_statement_name, query); 134 | 135 | -- Store the query plan after new indexes 136 | execute explain_plan_statement into plan_final; 137 | 138 | --raise notice '%', plan_final; 139 | 140 | -- Idenfity referenced indexes in new plan 141 | execute format( 142 | 'select 143 | coalesce(array_agg(hypopg_get_indexdef(indexrelid) order by indrelid, indkey::text), $i${}$i$::text[]) 144 | from 145 | %I.hypopg() 146 | where 147 | %s ilike ($i$%%$i$ || indexname || $i$%%$i$) 148 | ', 149 | hypopg_schema_name, 150 | quote_literal(plan_final)::text 151 | ) into statements; 152 | 153 | -- Reset all hypothetical indexes 154 | perform hypopg_reset(); 155 | 156 | -- Reset prepared statements 157 | deallocate all; 158 | 159 | return query values ( 160 | (plan_initial -> 0 -> 'Plan' -> 'Startup Cost'), 161 | (plan_final -> 0 -> 'Plan' -> 'Startup Cost'), 162 | (plan_initial -> 0 -> 'Plan' -> 'Total Cost'), 163 | (plan_final -> 0 -> 'Plan' -> 'Total Cost'), 164 | statements::text[] 165 | ); 166 | 167 | end; 168 | $$; 169 | -------------------------------------------------------------------------------- /index_advisor--0.2.0.sql: -------------------------------------------------------------------------------- 1 | create or replace function index_advisor( 2 | query text 3 | ) 4 | returns table ( 5 | startup_cost_before jsonb, 6 | startup_cost_after jsonb, 7 | total_cost_before jsonb, 8 | total_cost_after jsonb, 9 | index_statements text[], 10 | errors text[] 11 | ) 12 | volatile 13 | language plpgsql 14 | as $$ 15 | declare 16 | n_args int; 17 | prepared_statement_name text = 'index_advisor_working_statement'; 18 | hypopg_schema_name text = (select extnamespace::regnamespace::text from pg_extension where extname = 'hypopg'); 19 | explain_plan_statement text; 20 | error_message text; 21 | rec record; 22 | plan_initial jsonb; 23 | plan_final jsonb; 24 | statements text[] = '{}'; 25 | begin 26 | 27 | -- Remove comment lines (its common that they contain semicolons) 28 | query := trim( 29 | regexp_replace( 30 | regexp_replace( 31 | regexp_replace(query,'\/\*.+\*\/', '', 'g'), 32 | '--[^\r\n]*', ' ', 'g'), 33 | '\s+', ' ', 'g') 34 | ); 35 | 36 | -- Remove trailing semicolon 37 | query := regexp_replace(query, ';\s*$', ''); 38 | 39 | begin 40 | -- Disallow multiple statements 41 | if query ilike '%;%' then 42 | raise exception 'Query must not contain a semicolon'; 43 | end if; 44 | 45 | -- Hack to support PostgREST because the prepared statement for args incorrectly defaults to text 46 | query := replace(query, 'WITH pgrst_payload AS (SELECT $1 AS json_data)', 'WITH pgrst_payload AS (SELECT $1::json AS json_data)'); 47 | 48 | -- Create a prepared statement for the given query 49 | deallocate all; 50 | execute format('prepare %I as %s', prepared_statement_name, query); 51 | 52 | -- Detect how many arguments are present in the prepared statement 53 | n_args = ( 54 | select 55 | coalesce(array_length(parameter_types, 1), 0) 56 | from 57 | pg_prepared_statements 58 | where 59 | name = prepared_statement_name 60 | limit 61 | 1 62 | ); 63 | 64 | -- Create a SQL statement that can be executed to collect the explain plan 65 | explain_plan_statement = format( 66 | 'set local plan_cache_mode = force_generic_plan; explain (format json) execute %I%s', 67 | --'explain (format json) execute %I%s', 68 | prepared_statement_name, 69 | case 70 | when n_args = 0 then '' 71 | else format( 72 | '(%s)', array_to_string(array_fill('null'::text, array[n_args]), ',') 73 | ) 74 | end 75 | ); 76 | 77 | -- Store the query plan before any new indexes 78 | execute explain_plan_statement into plan_initial; 79 | 80 | -- Create possible indexes 81 | for rec in ( 82 | with extension_regclass as ( 83 | select 84 | distinct objid as oid 85 | from 86 | pg_catalog.pg_depend 87 | where 88 | deptype = 'e' 89 | ) 90 | select 91 | pc.relnamespace::regnamespace::text as schema_name, 92 | pc.relname as table_name, 93 | pa.attname as column_name, 94 | format( 95 | 'select %I.hypopg_create_index($i$create index on %I.%I(%I)$i$)', 96 | hypopg_schema_name, 97 | pc.relnamespace::regnamespace::text, 98 | pc.relname, 99 | pa.attname 100 | ) hypopg_statement 101 | from 102 | pg_catalog.pg_class pc 103 | join pg_catalog.pg_attribute pa 104 | on pc.oid = pa.attrelid 105 | left join extension_regclass er 106 | on pc.oid = er.oid 107 | left join pg_catalog.pg_index pi 108 | on pc.oid = pi.indrelid 109 | and (select array_agg(x) from unnest(pi.indkey) v(x)) = array[pa.attnum] 110 | and pi.indexprs is null -- ignore expression indexes 111 | and pi.indpred is null -- ignore partial indexes 112 | where 113 | pc.relnamespace::regnamespace::text not in ( -- ignore schema list 114 | 'pg_catalog', 'pg_toast', 'information_schema' 115 | ) 116 | and er.oid is null -- ignore entities owned by extensions 117 | and pc.relkind in ('r', 'm') -- regular tables, and materialized views 118 | and pc.relpersistence = 'p' -- permanent tables (not unlogged or temporary) 119 | and pa.attnum > 0 120 | and not pa.attisdropped 121 | and pi.indrelid is null 122 | and pa.atttypid in (20,16,1082,1184,1114,701,23,21,700,1083,2950,1700,25,18,1042,1043) 123 | ) 124 | loop 125 | -- Create the hypothetical index 126 | execute rec.hypopg_statement; 127 | end loop; 128 | 129 | /* 130 | for rec in select * from hypopg() 131 | loop 132 | raise notice '%', rec; 133 | end loop; 134 | */ 135 | 136 | -- Create a prepared statement for the given query 137 | -- The original prepared statement MUST be dropped because its plan is cached 138 | execute format('deallocate %I', prepared_statement_name); 139 | execute format('prepare %I as %s', prepared_statement_name, query); 140 | 141 | -- Store the query plan after new indexes 142 | execute explain_plan_statement into plan_final; 143 | 144 | --raise notice '%', plan_final; 145 | 146 | -- Idenfity referenced indexes in new plan 147 | execute format( 148 | 'select 149 | coalesce(array_agg(hypopg_get_indexdef(indexrelid) order by indrelid, indkey::text), $i${}$i$::text[]) 150 | from 151 | %I.hypopg() 152 | where 153 | %s ilike ($i$%%$i$ || indexname || $i$%%$i$) 154 | ', 155 | hypopg_schema_name, 156 | quote_literal(plan_final)::text 157 | ) into statements; 158 | 159 | -- Reset all hypothetical indexes 160 | perform hypopg_reset(); 161 | 162 | -- Reset prepared statements 163 | deallocate all; 164 | 165 | return query values ( 166 | (plan_initial -> 0 -> 'Plan' -> 'Startup Cost'), 167 | (plan_final -> 0 -> 'Plan' -> 'Startup Cost'), 168 | (plan_initial -> 0 -> 'Plan' -> 'Total Cost'), 169 | (plan_final -> 0 -> 'Plan' -> 'Total Cost'), 170 | statements::text[], 171 | array[]::text[] 172 | ); 173 | return; 174 | 175 | exception when others then 176 | get stacked diagnostics error_message = MESSAGE_TEXT; 177 | 178 | return query values ( 179 | null::jsonb, 180 | null::jsonb, 181 | null::jsonb, 182 | null::jsonb, 183 | array[]::text[], 184 | array[error_message]::text[] 185 | ); 186 | return; 187 | end; 188 | 189 | end; 190 | $$; 191 | -------------------------------------------------------------------------------- /index_advisor.control: -------------------------------------------------------------------------------- 1 | comment = 'Query index advisor' 2 | default_version = '0.2.0' 3 | relocatable = true 4 | requires = hypopg 5 | -------------------------------------------------------------------------------- /test/expected/disallow_semicolon.out: -------------------------------------------------------------------------------- 1 | begin; 2 | create extension index_advisor version '0.2.0' cascade; 3 | NOTICE: installing required extension "hypopg" 4 | -- This is okay because semicolon gets stripped from the end of the statement 5 | select * from index_advisor($$ select 1; $$); 6 | startup_cost_before | startup_cost_after | total_cost_before | total_cost_after | index_statements | errors 7 | ---------------------+--------------------+-------------------+------------------+------------------+-------- 8 | 0.00 | 0.00 | 0.01 | 0.01 | {} | {} 9 | (1 row) 10 | 11 | -- This is not okay because it contains multiple statements 12 | select * from index_advisor($$ select 1; select 1 $$); 13 | startup_cost_before | startup_cost_after | total_cost_before | total_cost_after | index_statements | errors 14 | ---------------------+--------------------+-------------------+------------------+------------------+---------------------------------------- 15 | | | | | {} | {"Query must not contain a semicolon"} 16 | (1 row) 17 | 18 | rollback; 19 | -------------------------------------------------------------------------------- /test/expected/integration.out: -------------------------------------------------------------------------------- 1 | begin; 2 | create extension index_advisor version '0.2.0' cascade; 3 | 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 | (0.00,4.07,25.88,13.54,"{""CREATE INDEX ON public.book USING btree (id)""}",{}) 14 | (1 row) 15 | 16 | rollback; 17 | -------------------------------------------------------------------------------- /test/expected/issue_1.out: -------------------------------------------------------------------------------- 1 | begin; 2 | create extension index_advisor version '0.2.0' cascade; 3 | NOTICE: installing required extension "hypopg" 4 | create table public.book( 5 | id int, 6 | -- json type is not btree indexable. In version 0.1.1 this raises the error 7 | -- ERROR: data type json has no default operator class for access method "btree" 8 | meta json 9 | ); 10 | select index_advisor($$ 11 | select * from book where id = $1 12 | $$); 13 | index_advisor 14 | --------------------------------------------------------------------------------- 15 | (0.00,4.07,25.88,13.54,"{""CREATE INDEX ON public.book USING btree (id)""}",{}) 16 | (1 row) 17 | 18 | rollback; 19 | -------------------------------------------------------------------------------- /test/expected/multi_index.out: -------------------------------------------------------------------------------- 1 | begin; 2 | create extension index_advisor version '0.2.0' cascade; 3 | NOTICE: installing required extension "hypopg" 4 | create table author( 5 | id serial primary key, 6 | name text not null 7 | ); 8 | create table publisher( 9 | id serial primary key, 10 | name text not null, 11 | corporate_address text 12 | ); 13 | create table book( 14 | id serial primary key, 15 | author_id int not null references author(id), 16 | publisher_id int not null references publisher(id), 17 | title text 18 | ); 19 | create table review( 20 | id serial primary key, 21 | book_id int references book(id), 22 | body text not null 23 | ); 24 | select 25 | * 26 | from 27 | index_advisor(' 28 | select 29 | book.id, 30 | book.title, 31 | publisher.name as publisher_name, 32 | author.name as author_name, 33 | review.body review_body 34 | from 35 | book 36 | join publisher 37 | on book.publisher_id = publisher.id 38 | join author 39 | on book.author_id = author.id 40 | join review 41 | on book.id = review.book_id 42 | where 43 | author.id = $1 44 | and publisher.id = $2 45 | '); 46 | startup_cost_before | startup_cost_after | total_cost_before | total_cost_after | index_statements | errors 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) 50 | 51 | rollback; 52 | -------------------------------------------------------------------------------- /test/expected/postgrest_query.out: -------------------------------------------------------------------------------- 1 | begin; 2 | create extension index_advisor version '0.2.0' 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; 14 | -------------------------------------------------------------------------------- /test/expected/semicolon_in_comment_query.out: -------------------------------------------------------------------------------- 1 | begin; 2 | -- Semicolons should be allowed in comments because they are common in prep stmts 3 | create extension index_advisor version '0.2.0' cascade; 4 | NOTICE: installing required extension "hypopg" 5 | create table public.book( 6 | id int, 7 | name text 8 | ); 9 | select index_advisor($$ 10 | -- some comment with a semicolon; 11 | select * from book where id = $1 12 | $$); 13 | index_advisor 14 | --------------------------------------------------------------------------------- 15 | (0.00,4.07,25.88,13.54,"{""CREATE INDEX ON public.book USING btree (id)""}",{}) 16 | (1 row) 17 | 18 | rollback; 19 | -------------------------------------------------------------------------------- /test/expected/unknown_parameter_type.out: -------------------------------------------------------------------------------- 1 | begin; 2 | -- Semicolons should be allowed in comments because they are common in prep stmts 3 | create extension index_advisor version '0.2.0' cascade; 4 | NOTICE: installing required extension "hypopg" 5 | select * from index_advisor( 6 | 'SELECT concat(schemaname, $1, tablename, $2, policyname) as policy 7 | FROM pg_policies 8 | ORDER BY 1 desc' 9 | ); 10 | startup_cost_before | startup_cost_after | total_cost_before | total_cost_after | index_statements | errors 11 | ---------------------+--------------------+-------------------+------------------+------------------+--------------------------------------------------- 12 | | | | | {} | {"could not determine data type of parameter $1"} 13 | (1 row) 14 | 15 | rollback; 16 | -------------------------------------------------------------------------------- /test/sql/disallow_semicolon.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | 3 | create extension index_advisor version '0.2.0' cascade; 4 | 5 | -- This is okay because semicolon gets stripped from the end of the statement 6 | select * from index_advisor($$ select 1; $$); 7 | 8 | -- This is not okay because it contains multiple statements 9 | select * from index_advisor($$ select 1; select 1 $$); 10 | 11 | rollback; 12 | -------------------------------------------------------------------------------- /test/sql/integration.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | 3 | create extension index_advisor version '0.2.0' cascade; 4 | 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 | $$); 13 | 14 | rollback; 15 | -------------------------------------------------------------------------------- /test/sql/issue_1.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | 3 | create extension index_advisor version '0.2.0' cascade; 4 | 5 | create table public.book( 6 | id int, 7 | -- json type is not btree indexable. In version 0.1.1 this raises the error 8 | -- ERROR: data type json has no default operator class for access method "btree" 9 | meta json 10 | ); 11 | 12 | select index_advisor($$ 13 | select * from book where id = $1 14 | $$); 15 | 16 | rollback; 17 | -------------------------------------------------------------------------------- /test/sql/multi_index.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | 3 | create extension index_advisor version '0.2.0' cascade; 4 | 5 | create table author( 6 | id serial primary key, 7 | name text not null 8 | ); 9 | 10 | create table publisher( 11 | id serial primary key, 12 | name text not null, 13 | corporate_address text 14 | ); 15 | 16 | create table book( 17 | id serial primary key, 18 | author_id int not null references author(id), 19 | publisher_id int not null references publisher(id), 20 | title text 21 | ); 22 | 23 | create table review( 24 | id serial primary key, 25 | book_id int references book(id), 26 | body text not null 27 | ); 28 | 29 | select 30 | * 31 | from 32 | index_advisor(' 33 | select 34 | book.id, 35 | book.title, 36 | publisher.name as publisher_name, 37 | author.name as author_name, 38 | review.body review_body 39 | from 40 | book 41 | join publisher 42 | on book.publisher_id = publisher.id 43 | join author 44 | on book.author_id = author.id 45 | join review 46 | on book.id = review.book_id 47 | where 48 | author.id = $1 49 | and publisher.id = $2 50 | '); 51 | 52 | rollback; 53 | -------------------------------------------------------------------------------- /test/sql/postgrest_query.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | 3 | create extension index_advisor version '0.2.0' 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; 12 | -------------------------------------------------------------------------------- /test/sql/semicolon_in_comment_query.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | -- Semicolons should be allowed in comments because they are common in prep stmts 3 | create extension index_advisor version '0.2.0' cascade; 4 | 5 | create table public.book( 6 | id int, 7 | name text 8 | ); 9 | 10 | select index_advisor($$ 11 | -- some comment with a semicolon; 12 | select * from book where id = $1 13 | $$); 14 | 15 | rollback; 16 | -------------------------------------------------------------------------------- /test/sql/unknown_parameter_type.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | -- Semicolons should be allowed in comments because they are common in prep stmts 3 | create extension index_advisor version '0.2.0' cascade; 4 | 5 | select * from index_advisor( 6 | 'SELECT concat(schemaname, $1, tablename, $2, policyname) as policy 7 | FROM pg_policies 8 | ORDER BY 1 desc' 9 | ); 10 | 11 | rollback; 12 | --------------------------------------------------------------------------------