Skip to content

[PGPRO-5435] Added functions that output top(n) execution time queries and top(n) cardinality error queries without using aqo. #45

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Closed
wants to merge 1 commit into from
Closed
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
3 changes: 2 additions & 1 deletion Makefile
Original file line number Diff line number Diff line change
Expand Up @@ -21,7 +21,8 @@ REGRESS = aqo_disabled \
gucs \
forced_stat_collection \
unsupported \
clean_aqo_data
clean_aqo_data \
top_queries

fdw_srcdir = $(top_srcdir)/contrib/postgres_fdw
PG_CPPFLAGS += -I$(libpq_srcdir) -I$(fdw_srcdir)
Expand Down
33 changes: 29 additions & 4 deletions aqo--1.2--1.3.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,11 +7,10 @@ DECLARE
aqo_query_texts_row aqo_query_texts%ROWTYPE;
aqo_query_stat_row aqo_query_stat%ROWTYPE;
oid_var oid;
fspace_hash_var numeric;
fspace_hash_var int;
delete_row boolean DEFAULT false;
BEGIN
RAISE NOTICE 'Cleaning aqo_data records';

FOR aqo_data_row IN
SELECT * FROM aqo_data
LOOP
Expand All @@ -25,15 +24,13 @@ BEGIN
END IF;
END LOOP;
END IF;

FOR aqo_queries_row IN
SELECT * FROM aqo_queries
LOOP
IF (delete_row = true AND
fspace_hash_var <> 0 AND
fspace_hash_var = aqo_queries_row.fspace_hash AND
aqo_queries_row.fspace_hash = aqo_queries_row.query_hash) THEN

DELETE FROM aqo_data WHERE aqo_data = aqo_data_row;
DELETE FROM aqo_queries WHERE aqo_queries = aqo_queries_row;
FOR aqo_query_texts_row IN
Expand All @@ -52,4 +49,32 @@ BEGIN
END LOOP;
END LOOP;
END;
$$ LANGUAGE plpgsql;

CREATE OR REPLACE FUNCTION public.top_execution_time_queries(n int)
RETURNS TABLE(num bigint,
class int,
execution_time double precision[]
)
AS $$
BEGIN
RAISE NOTICE 'Top % execution time classes of queries', n;
RETURN QUERY SELECT row_number() OVER(ORDER BY execution_time_without_aqo DESC) num, aqo_query_stat.query_hash, execution_time_without_aqo
FROM aqo_query_stat RIGHT OUTER JOIN aqo_queries ON aqo_queries.fspace_hash = aqo_query_stat.query_hash WHERE aqo_query_stat.query_hash <> 0
GROUP BY aqo_query_stat.query_hash ORDER BY execution_time_without_aqo DESC LIMIT n;
END;
$$ LANGUAGE plpgsql;

CREATE OR REPLACE FUNCTION public.top_cardinality_error_queries(n int)
RETURNS TABLE(num bigint,
class int,
cardinality_error double precision[]
)
AS $$
BEGIN
RAISE NOTICE 'Top % cardinality error classes of queries', n;
RETURN QUERY SELECT row_number() OVER(ORDER BY cardinality_error_without_aqo DESC) num, aqo_query_stat.query_hash, cardinality_error_without_aqo
FROM aqo_query_stat RIGHT OUTER JOIN aqo_queries ON aqo_queries.fspace_hash = aqo_query_stat.query_hash WHERE aqo_query_stat.query_hash <> 0
GROUP BY aqo_query_stat.query_hash ORDER BY cardinality_error_without_aqo DESC LIMIT n;
END;
$$ LANGUAGE plpgsql;
52 changes: 52 additions & 0 deletions expected/top_queries.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,52 @@
CREATE EXTENSION aqo;
ERROR: extension "aqo" already exists
SET aqo.mode = 'disabled';
SET aqo.force_collect_stat = 'on';
--
-- num of generate_series(1,1000000) query should be the first
--
SELECT count(*) FROM generate_series(1,1000000);
count
---------
1000000
(1 row)

SELECT num FROM top_execution_time_queries(10) WHERE
class = (SELECT fspace_hash FROM aqo_queries WHERE
aqo_queries.query_hash = (SELECT aqo_query_texts.query_hash FROM aqo_query_texts
WHERE query_text = 'SELECT count(*) FROM generate_series(1,1000000);'));
NOTICE: Top 10 execution time classes of queries
num
-----
1
(1 row)

--
-- num of query uses t2 should be bigger than num of query uses t1 and be the fisrt
--
CREATE TABLE t1 AS SELECT mod(gs,10) AS x, mod(gs+1,10) AS y
FROM generate_series(1,1000) AS gs;
CREATE TABLE t2 AS SELECT mod(gs,10) AS x, mod(gs+1,10) AS y
FROM generate_series(1,100000) AS gs;
SELECT count(*) FROM (SELECT x, y FROM t1 GROUP BY GROUPING SETS ((x,y), (x), (y), ())) AS q1;
count
-------
31
(1 row)

SELECT count(*) FROM (SELECT x, y FROM t2 GROUP BY GROUPING SETS ((x,y), (x), (y), ())) AS q1;
count
-------
31
(1 row)

SELECT num FROM top_cardinality_error_queries(10) WHERE
class = (SELECT fspace_hash FROM aqo_queries WHERE
aqo_queries.query_hash = (SELECT aqo_query_texts.query_hash FROM aqo_query_texts
WHERE query_text = 'SELECT count(*) FROM (SELECT x, y FROM t2 GROUP BY GROUPING SETS ((x,y), (x), (y), ())) AS q1;'));
NOTICE: Top 10 cardinality error classes of queries
num
-----
1
(1 row)

27 changes: 27 additions & 0 deletions sql/top_queries.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,27 @@
CREATE EXTENSION aqo;
SET aqo.mode = 'disabled';
SET aqo.force_collect_stat = 'on';

--
-- num of generate_series(1,1000000) query should be the first
--
SELECT count(*) FROM generate_series(1,1000000);
SELECT num FROM top_execution_time_queries(10) WHERE
class = (SELECT fspace_hash FROM aqo_queries WHERE
aqo_queries.query_hash = (SELECT aqo_query_texts.query_hash FROM aqo_query_texts
WHERE query_text = 'SELECT count(*) FROM generate_series(1,1000000);'));

--
-- num of query uses t2 should be bigger than num of query uses t1 and be the fisrt
--
CREATE TABLE t1 AS SELECT mod(gs,10) AS x, mod(gs+1,10) AS y
FROM generate_series(1,1000) AS gs;
CREATE TABLE t2 AS SELECT mod(gs,10) AS x, mod(gs+1,10) AS y
FROM generate_series(1,100000) AS gs;
SELECT count(*) FROM (SELECT x, y FROM t1 GROUP BY GROUPING SETS ((x,y), (x), (y), ())) AS q1;
SELECT count(*) FROM (SELECT x, y FROM t2 GROUP BY GROUPING SETS ((x,y), (x), (y), ())) AS q1;

SELECT num FROM top_cardinality_error_queries(10) WHERE
class = (SELECT fspace_hash FROM aqo_queries WHERE
aqo_queries.query_hash = (SELECT aqo_query_texts.query_hash FROM aqo_query_texts
WHERE query_text = 'SELECT count(*) FROM (SELECT x, y FROM t2 GROUP BY GROUPING SETS ((x,y), (x), (y), ())) AS q1;'));