Skip to content

Commit

Permalink
catch all errors during execution
Browse files Browse the repository at this point in the history
  • Loading branch information
olirice committed Apr 17, 2023
1 parent 4421c56 commit c4d1ab3
Show file tree
Hide file tree
Showing 3 changed files with 49 additions and 14 deletions.
37 changes: 23 additions & 14 deletions index_advisor--0.2.0.sql
Expand Up @@ -17,6 +17,7 @@ declare
prepared_statement_name text = 'index_advisor_working_statement';
hypopg_schema_name text = (select extnamespace::regnamespace::text from pg_extension where extname = 'hypopg');
explain_plan_statement text;
error_message text;
rec record;
plan_initial jsonb;
plan_final jsonb;
Expand All @@ -35,17 +36,12 @@ begin
-- Remove trailing semicolon
query := regexp_replace(query, ';\s*$', '');

-- Disallow multiple statements
if query ilike '%;%' then
return query values (
null::jsonb,
null::jsonb,
null::jsonb,
null::jsonb,
array[]::text[],
array['Query must not contain a semicolon']::text[]
);
else
begin
-- Disallow multiple statements
if query ilike '%;%' then
raise exception 'Query must not contain a semicolon';
end if;

-- Hack to support PostgREST because the prepared statement for args incorrectly defaults to text
query := replace(query, 'WITH pgrst_payload AS (SELECT $1 AS json_data)', 'WITH pgrst_payload AS (SELECT $1::json AS json_data)');

Expand Down Expand Up @@ -87,7 +83,7 @@ begin
select
distinct objid as oid
from
pg_depend
pg_catalog.pg_depend
where
deptype = 'e'
)
Expand All @@ -108,7 +104,7 @@ begin
on pc.oid = pa.attrelid
left join extension_regclass er
on pc.oid = er.oid
left join pg_index pi
left join pg_catalog.pg_index pi
on pc.oid = pi.indrelid
and (select array_agg(x) from unnest(pi.indkey) v(x)) = array[pa.attnum]
and pi.indexprs is null -- ignore expression indexes
Expand Down Expand Up @@ -174,8 +170,21 @@ begin
statements::text[],
array[]::text[]
);
return;

end if;
exception when others then
get stacked diagnostics error_message = MESSAGE_TEXT;

return query values (
null::jsonb,
null::jsonb,
null::jsonb,
null::jsonb,
array[]::text[],
array[error_message]::text[]
);
return;
end;

end;
$$;
15 changes: 15 additions & 0 deletions test/expected/unknown_parameter_type.out
@@ -0,0 +1,15 @@
begin;
-- Semicolons should be allowed in comments because they are common in prep stmts
create extension index_advisor version '0.2.0' cascade;
NOTICE: installing required extension "hypopg"
select * from index_advisor(
'SELECT concat(schemaname, $1, tablename, $2, policyname) as policy
FROM pg_policies
ORDER BY 1 desc'
);
startup_cost_before | startup_cost_after | total_cost_before | total_cost_after | index_statements | errors
---------------------+--------------------+-------------------+------------------+------------------+---------------------------------------------------
| | | | {} | {"could not determine data type of parameter $1"}
(1 row)

rollback;
11 changes: 11 additions & 0 deletions test/sql/unknown_parameter_type.sql
@@ -0,0 +1,11 @@
begin;
-- Semicolons should be allowed in comments because they are common in prep stmts
create extension index_advisor version '0.2.0' cascade;

select * from index_advisor(
'SELECT concat(schemaname, $1, tablename, $2, policyname) as policy
FROM pg_policies
ORDER BY 1 desc'
);

rollback;

0 comments on commit c4d1ab3

Please sign in to comment.