forked from ossc-db/pg_plan_advsr
-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Add ExplainOneQuery hook to show query info and suggestions - Rename some columns name and add new column to plan_history table - Add new view plan_history_pretty to improve readability - fix printf format for queryid - Add extended stats suggestion feature: get_extstat() - Update document
- Loading branch information
1 parent
0429704
commit 0dfd7b0
Showing
9 changed files
with
560 additions
and
268 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,154 @@ | ||
-- complain if script is sourced in psql, rather than via CREATE EXTENSION | ||
\echo Use "CREATE EXTENSION pg_plan_advsr" to load this file. \quit | ||
|
||
SET search_path = public; | ||
SET LOCAL client_min_messages = WARNING; | ||
|
||
CREATE SCHEMA plan_repo; | ||
|
||
-- Register tables | ||
CREATE TABLE plan_repo.plan_history | ||
( | ||
id serial, | ||
norm_query_hash text, | ||
pgsp_queryid bigint, | ||
pgsp_planid bigint, | ||
execution_time double precision, | ||
rows_hint text, | ||
scan_hint text, | ||
join_hint text, | ||
lead_hint text, | ||
scan_rows_err double precision, | ||
scan_err_ratio double precision, | ||
join_rows_err double precision, | ||
join_err_ratio double precision, | ||
scan_cnt int, | ||
join_cnt int, | ||
application_name text, | ||
timestamp timestamp | ||
); | ||
|
||
CREATE TABLE plan_repo.norm_queries | ||
( | ||
norm_query_hash text, | ||
norm_query_string text | ||
); | ||
|
||
CREATE TABLE plan_repo.raw_queries | ||
( | ||
norm_query_hash text, | ||
raw_query_id serial, | ||
raw_query_string text, | ||
timestamp timestamp | ||
); | ||
|
||
-- Register view | ||
CREATE VIEW plan_repo.plan_history_pretty | ||
AS | ||
SELECT id, | ||
norm_query_hash, | ||
pgsp_queryid, | ||
pgsp_planid, | ||
execution_time::numeric(18, 3), | ||
rows_hint, | ||
scan_hint, | ||
join_hint, | ||
lead_hint, | ||
scan_rows_err, | ||
scan_err_ratio::numeric(18, 2), | ||
join_rows_err, | ||
join_err_ratio::numeric(18, 2), | ||
scan_cnt, | ||
join_cnt, | ||
application_name, | ||
timestamp | ||
FROM plan_repo.plan_history | ||
ORDER BY id; | ||
|
||
-- Register functions | ||
CREATE FUNCTION pg_plan_advsr_enable_feedback() | ||
RETURNS void | ||
AS 'MODULE_PATHNAME' | ||
LANGUAGE C; | ||
|
||
CREATE FUNCTION pg_plan_advsr_disable_feedback() | ||
RETURNS void | ||
AS 'MODULE_PATHNAME' | ||
LANGUAGE C; | ||
|
||
CREATE OR REPLACE FUNCTION plan_repo.get_hint(bigint) | ||
RETURNS text | ||
AS 'select ''/*+'' || chr(10) || ' | ||
'lead_hint || chr(10) || ' | ||
'join_hint || chr(10) || ' | ||
'scan_hint || chr(10) || ' | ||
'''*/'' || chr(10) || ' | ||
'''--'' || pgsp_planid ' | ||
'from plan_repo.plan_history ' | ||
'where pgsp_planid = $1 ' | ||
'order by id desc ' | ||
'limit 1;' | ||
LANGUAGE SQL | ||
IMMUTABLE | ||
RETURNS NULL ON NULL INPUT; | ||
|
||
-- This function can use on PG14 or above with pg_qualstats | ||
CREATE OR REPLACE FUNCTION plan_repo.get_extstat(bigint) | ||
RETURNS TABLE (suggest text) AS $$ | ||
with all_quals as ( | ||
--左 | ||
SELECT qualid, | ||
lrelid as rel, | ||
pg_catalog.quote_ident(n.nspname) || '.' || | ||
pg_catalog.quote_ident(c.relname) as relname, | ||
pg_qualstats_get_idx_col(qualnodeid, true) as col | ||
FROM pg_qualstats() q | ||
JOIN pg_catalog.pg_class c ON q.lrelid = c.oid | ||
JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace | ||
WHERE queryid = $1 | ||
UNION | ||
--右 | ||
SELECT qualid, | ||
rrelid as rel, | ||
pg_catalog.quote_ident(n.nspname) || '.' || | ||
pg_catalog.quote_ident(c.relname) as relname, | ||
pg_qualstats_get_idx_col(qualnodeid, true) as col | ||
FROM pg_qualstats() q | ||
JOIN pg_catalog.pg_class c ON q.rrelid = c.oid | ||
JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace | ||
WHERE queryid = $1 | ||
), | ||
data as ( | ||
select relname, | ||
col | ||
from all_quals | ||
where col is not null | ||
group by relname, col | ||
ORDER BY 1, 2 | ||
), | ||
rels_cols as ( | ||
select relname, | ||
array_to_string(array_agg(col), ', ') as cols, | ||
count(col) as col_num | ||
from data | ||
group by relname | ||
), | ||
nominated as ( | ||
select relname, | ||
cols | ||
from rels_cols | ||
where col_num > 1 | ||
) | ||
select 'CREATE STATISTICS ON ' || array_to_string(array_agg(cols), ', ') || ' ' || | ||
'FROM '|| relname || ';' as suggest | ||
from nominated | ||
group by relname | ||
ORDER BY 1; | ||
$$ LANGUAGE sql; | ||
|
||
|
||
-- Grant | ||
GRANT SELECT ON plan_repo.plan_history TO PUBLIC; | ||
GRANT SELECT ON plan_repo.norm_queries TO PUBLIC; | ||
GRANT SELECT ON plan_repo.raw_queries TO PUBLIC; | ||
GRANT USAGE ON SCHEMA plan_repo TO PUBLIC; |
Oops, something went wrong.