Show query text in EXPLAIN output

pull/3891/head
Hadi Moshayedi 2020-06-09 19:00:16 -07:00
parent 9a49f10c49
commit 1f6d6ee4a5
6 changed files with 86 additions and 10 deletions

View File

@ -602,6 +602,12 @@ ExplainTask(Task *task, int placementIndex, List *explainOutputList, ExplainStat
es->indent += 3;
}
if (es->verbose)
{
const char *queryText = TaskQueryStringForAllPlacements(task);
ExplainPropertyText("Query", queryText, es);
}
if (explainOutputList != NIL)
{
List *taskPlacementList = task->taskPlacementList;

View File

@ -310,6 +310,51 @@ Aggregate (actual rows=1 loops=1)
Merge Task Count: 4
END;
DROP TABLE t1, t2;
-- Test query text output, with ANALYZE ON
EXPLAIN (COSTS FALSE, ANALYZE TRUE, TIMING FALSE, SUMMARY FALSE, VERBOSE TRUE)
SELECT l_quantity, count(*) count_quantity FROM lineitem
GROUP BY l_quantity ORDER BY count_quantity, l_quantity;
Sort (actual rows=50 loops=1)
Output: remote_scan.l_quantity, (COALESCE((pg_catalog.sum(remote_scan.count_quantity))::bigint, '0'::bigint))
Sort Key: (COALESCE((pg_catalog.sum(remote_scan.count_quantity))::bigint, '0'::bigint)), remote_scan.l_quantity
Sort Method: quicksort Memory: 27kB
-> HashAggregate (actual rows=50 loops=1)
Output: remote_scan.l_quantity, COALESCE((pg_catalog.sum(remote_scan.count_quantity))::bigint, '0'::bigint)
Group Key: remote_scan.l_quantity
-> Custom Scan (Citus Adaptive) (actual rows=100 loops=1)
Output: remote_scan.l_quantity, remote_scan.count_quantity
Task Count: 2
Tasks Shown: One of 2
-> Task
Query: SELECT l_quantity, count(*) AS count_quantity FROM lineitem_290000 lineitem WHERE true GROUP BY l_quantity
Node: host=localhost port=xxxxx dbname=regression
-> HashAggregate (actual rows=50 loops=1)
Output: l_quantity, count(*)
Group Key: lineitem.l_quantity
-> Seq Scan on public.lineitem_290000 lineitem (actual rows=6000 loops=1)
Output: l_orderkey, l_partkey, l_suppkey, l_linenumber, l_quantity, l_extendedprice, l_discount, l_tax, l_returnflag, l_linestatus, l_shipdate, l_commitdate, l_receiptdate, l_shipinstruct, l_shipmode, l_comment
-- Test query text output, with ANALYZE OFF
EXPLAIN (COSTS FALSE, ANALYZE FALSE, TIMING FALSE, SUMMARY FALSE, VERBOSE TRUE)
SELECT l_quantity, count(*) count_quantity FROM lineitem
GROUP BY l_quantity ORDER BY count_quantity, l_quantity;
Sort
Output: remote_scan.l_quantity, (COALESCE((pg_catalog.sum(remote_scan.count_quantity))::bigint, '0'::bigint))
Sort Key: (COALESCE((pg_catalog.sum(remote_scan.count_quantity))::bigint, '0'::bigint)), remote_scan.l_quantity
-> HashAggregate
Output: remote_scan.l_quantity, COALESCE((pg_catalog.sum(remote_scan.count_quantity))::bigint, '0'::bigint)
Group Key: remote_scan.l_quantity
-> Custom Scan (Citus Adaptive)
Output: remote_scan.l_quantity, remote_scan.count_quantity
Task Count: 2
Tasks Shown: One of 2
-> Task
Query: SELECT l_quantity, count(*) AS count_quantity FROM lineitem_290000 lineitem WHERE true GROUP BY l_quantity
Node: host=localhost port=xxxxx dbname=regression
-> HashAggregate
Output: l_quantity, count(*)
Group Key: lineitem.l_quantity
-> Seq Scan on public.lineitem_290000 lineitem
Output: l_orderkey, l_partkey, l_suppkey, l_linenumber, l_quantity, l_extendedprice, l_discount, l_tax, l_returnflag, l_linestatus, l_shipdate, l_commitdate, l_receiptdate, l_shipinstruct, l_shipmode, l_comment
-- Test verbose
EXPLAIN (COSTS FALSE, VERBOSE TRUE)
SELECT sum(l_quantity) / avg(l_quantity) FROM lineitem;
@ -320,6 +365,7 @@ Aggregate
Task Count: 2
Tasks Shown: One of 2
-> Task
Query: SELECT sum(l_quantity), sum(l_quantity), count(l_quantity) FROM lineitem_290000 lineitem WHERE true
Node: host=localhost port=xxxxx dbname=regression
-> Aggregate
Output: sum(l_quantity), sum(l_quantity), count(l_quantity)
@ -454,6 +500,7 @@ Aggregate
Task Count: 2
Tasks Shown: One of 2
-> Task
Query: SELECT sum(l_quantity), sum(l_quantity), count(l_quantity), sum(l_quantity) AS worker_column_4 FROM lineitem_290000 lineitem WHERE true
Node: host=localhost port=xxxxx dbname=regression
-> Aggregate
Output: sum(l_quantity), sum(l_quantity), count(l_quantity), sum(l_quantity)
@ -473,6 +520,7 @@ HashAggregate
Task Count: 2
Tasks Shown: One of 2
-> Task
Query: SELECT l_quantity, l_quantity AS worker_column_2 FROM lineitem_290000 lineitem WHERE true GROUP BY l_quantity
Node: host=localhost port=xxxxx dbname=regression
-> HashAggregate
Output: l_quantity, l_quantity
@ -1320,6 +1368,7 @@ Custom Scan (Citus Adaptive)
Task Count: 4
Tasks Shown: One of 4
-> Task
Query: SELECT DISTINCT l_orderkey FROM lineitem_hash_part_360041 lineitem_hash_part WHERE true
Node: host=localhost port=xxxxx dbname=regression
-> HashAggregate
Output: l_orderkey
@ -1333,6 +1382,7 @@ Custom Scan (Citus Adaptive)
Task Count: 1
Tasks Shown: All
-> Task
Query: SELECT keys.l_orderkey FROM ((SELECT intermediate_result.s FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result(s integer)) series JOIN (SELECT intermediate_result.l_orderkey FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(l_orderkey bigint)) keys ON ((series.s OPERATOR(pg_catalog.=) keys.l_orderkey))) ORDER BY series.s
Node: host=localhost port=xxxxx dbname=regression
-> Merge Join
Output: intermediate_result_1.l_orderkey, intermediate_result.s

View File

@ -292,6 +292,7 @@ Aggregate
Task Count: 16
Tasks Shown: One of 16
-> Task
Query: SELECT sum(l_quantity), sum(l_quantity), count(l_quantity) FROM lineitem_mx_1220052 lineitem_mx WHERE true
Node: host=localhost port=xxxxx dbname=regression
-> Aggregate
Output: sum(l_quantity), sum(l_quantity), count(l_quantity)

View File

@ -709,7 +709,7 @@ EXPLAIN (COSTS FALSE, VERBOSE TRUE)
user_id)) AS ftop
ORDER BY 2 DESC, 1 DESC
LIMIT 5;
QUERY PLAN
QUERY PLAN
---------------------------------------------------------------------
Limit
Output: remote_scan.user_id, remote_scan.sum
@ -721,6 +721,7 @@ EXPLAIN (COSTS FALSE, VERBOSE TRUE)
Task Count: 4
Tasks Shown: One of 4
-> Task
Query: SELECT worker_column_1 AS user_id, worker_column_2 AS sum FROM (SELECT ftop.user_id AS worker_column_1, ftop.sum AS worker_column_2 FROM (SELECT user_id_1.user_id, sum(user_id_1.counter) AS sum FROM (SELECT users_table.user_id, sum(users_table.value_2) OVER (PARTITION BY users_table.user_id) AS counter FROM public.users_table_1400256 users_table UNION SELECT events_table.user_id, sum(events_table.value_2) OVER (PARTITION BY events_table.user_id) AS counter FROM public.events_table_1400260 events_table) user_id_1 GROUP BY user_id_1.user_id UNION SELECT user_id_2.user_id, sum(user_id_2.counter) AS sum FROM (SELECT users_table.user_id, sum(users_table.value_2) OVER (PARTITION BY users_table.user_id) AS counter FROM public.users_table_1400256 users_table UNION SELECT events_table.user_id, sum(events_table.value_2) OVER (PARTITION BY events_table.user_id) AS counter FROM public.events_table_1400260 events_table) user_id_2 GROUP BY user_id_2.user_id) ftop) worker_subquery ORDER BY worker_column_2 DESC, worker_column_1 DESC LIMIT '5'::bigint
Node: host=localhost port=xxxxx dbname=regression
-> Limit
Output: users_table.user_id, (sum((sum(users_table.value_2) OVER (?))))
@ -773,7 +774,7 @@ EXPLAIN (COSTS FALSE, VERBOSE TRUE)
Sort Key: events_table_1.user_id
-> Seq Scan on public.events_table_1400260 events_table_1
Output: events_table_1.user_id, events_table_1.value_2
(62 rows)
(63 rows)
-- test with window functions which aren't pushed down
SELECT

View File

@ -74,6 +74,7 @@ SELECT
Task Count: 8
Tasks Shown: One of 8
-> Task
Query: SELECT l_orderkey, count(DISTINCT l_partkey) AS count FROM lineitem_hash_240000 lineitem_hash WHERE true GROUP BY l_orderkey ORDER BY (count(DISTINCT l_partkey)) DESC, l_orderkey DESC LIMIT '10'::bigint
Node: host=localhost port=57637 dbname=regression
-> Limit
Output: l_orderkey, (count(DISTINCT l_partkey))
@ -85,7 +86,7 @@ SELECT
Group Key: lineitem_hash.l_orderkey
-> Index Scan Backward using lineitem_hash_pkey_240000 on public.lineitem_hash_240000 lineitem_hash
Output: l_orderkey, l_partkey, l_suppkey, l_linenumber, l_quantity, l_extendedprice, l_discount, l_tax, l_returnflag, l_linestatus, l_shipdate, l_commitdate, l_receiptdate, l_shipinstruct, l_shipmode, l_comment
(21 rows)
(22 rows)
-- it is also supported if there is no grouping or grouping is on non-partition field
SELECT
@ -118,13 +119,14 @@ SELECT
Task Count: 8
Tasks Shown: One of 8
-> Task
Query: SELECT l_partkey AS count FROM lineitem_hash_240000 lineitem_hash WHERE true GROUP BY l_partkey
Node: host=localhost port=57637 dbname=regression
-> HashAggregate
Output: l_partkey
Group Key: lineitem_hash.l_partkey
-> Seq Scan on public.lineitem_hash_240000 lineitem_hash
Output: l_orderkey, l_partkey, l_suppkey, l_linenumber, l_quantity, l_extendedprice, l_discount, l_tax, l_returnflag, l_linestatus, l_shipdate, l_commitdate, l_receiptdate, l_shipinstruct, l_shipmode, l_comment
(18 rows)
(19 rows)
SELECT
l_shipmode, count(DISTINCT l_partkey)
@ -168,13 +170,14 @@ SELECT
Task Count: 8
Tasks Shown: One of 8
-> Task
Query: SELECT l_shipmode, l_partkey AS count FROM lineitem_hash_240000 lineitem_hash WHERE true GROUP BY l_shipmode, l_partkey
Node: host=localhost port=57637 dbname=regression
-> HashAggregate
Output: l_shipmode, l_partkey
Group Key: lineitem_hash.l_shipmode, lineitem_hash.l_partkey
-> Seq Scan on public.lineitem_hash_240000 lineitem_hash
Output: l_orderkey, l_partkey, l_suppkey, l_linenumber, l_quantity, l_extendedprice, l_discount, l_tax, l_returnflag, l_linestatus, l_shipdate, l_commitdate, l_receiptdate, l_shipinstruct, l_shipmode, l_comment
(22 rows)
(23 rows)
-- mixed mode count distinct, grouped by partition column
SELECT
@ -216,6 +219,7 @@ SELECT
Task Count: 8
Tasks Shown: One of 8
-> Task
Query: SELECT l_orderkey, count(DISTINCT l_partkey) AS count, count(DISTINCT l_shipmode) AS count FROM lineitem_hash_240000 lineitem_hash WHERE true GROUP BY l_orderkey ORDER BY (count(DISTINCT l_shipmode)) DESC, (count(DISTINCT l_partkey)) DESC, l_orderkey LIMIT '10'::bigint
Node: host=localhost port=57637 dbname=regression
-> Limit
Output: l_orderkey, (count(DISTINCT l_partkey)), (count(DISTINCT l_shipmode))
@ -227,7 +231,7 @@ SELECT
Group Key: lineitem_hash.l_orderkey
-> Index Scan using lineitem_hash_pkey_240000 on public.lineitem_hash_240000 lineitem_hash
Output: l_orderkey, l_partkey, l_suppkey, l_linenumber, l_quantity, l_extendedprice, l_discount, l_tax, l_returnflag, l_linestatus, l_shipdate, l_commitdate, l_receiptdate, l_shipinstruct, l_shipmode, l_comment
(21 rows)
(22 rows)
-- partition/non-partition column count distinct no grouping
SELECT
@ -251,13 +255,14 @@ SELECT
Task Count: 8
Tasks Shown: One of 8
-> Task
Query: SELECT l_orderkey AS count, l_partkey AS count, l_shipmode AS count FROM lineitem_hash_240000 lineitem_hash WHERE true GROUP BY l_orderkey, l_partkey, l_shipmode
Node: host=localhost port=57637 dbname=regression
-> HashAggregate
Output: l_orderkey, l_partkey, l_shipmode
Group Key: lineitem_hash.l_orderkey, lineitem_hash.l_partkey, lineitem_hash.l_shipmode
-> Seq Scan on public.lineitem_hash_240000 lineitem_hash
Output: l_orderkey, l_partkey, l_suppkey, l_linenumber, l_quantity, l_extendedprice, l_discount, l_tax, l_returnflag, l_linestatus, l_shipdate, l_commitdate, l_receiptdate, l_shipinstruct, l_shipmode, l_comment
(13 rows)
(14 rows)
-- distinct/non-distinct on partition and non-partition columns
SELECT
@ -375,13 +380,14 @@ SELECT
Task Count: 8
Tasks Shown: One of 8
-> Task
Query: SELECT l_shipmode, l_partkey AS count, l_suppkey AS worker_column_3 FROM lineitem_hash_240000 lineitem_hash WHERE true GROUP BY l_shipmode, l_partkey, l_suppkey
Node: host=localhost port=57637 dbname=regression
-> HashAggregate
Output: l_shipmode, l_partkey, l_suppkey
Group Key: lineitem_hash.l_shipmode, lineitem_hash.l_partkey, lineitem_hash.l_suppkey
-> Seq Scan on public.lineitem_hash_240000 lineitem_hash
Output: l_orderkey, l_partkey, l_suppkey, l_linenumber, l_quantity, l_extendedprice, l_discount, l_tax, l_returnflag, l_linestatus, l_shipdate, l_commitdate, l_receiptdate, l_shipinstruct, l_shipmode, l_comment
(21 rows)
(22 rows)
-- count distinct is supported on single table subqueries
SELECT *
@ -497,6 +503,7 @@ SELECT
Task Count: 8
Tasks Shown: One of 8
-> Task
Query: SELECT l_orderkey, count(DISTINCT l_suppkey) FILTER (WHERE (l_shipmode OPERATOR(pg_catalog.=) 'AIR'::bpchar)) AS count, count(DISTINCT l_suppkey) AS count FROM lineitem_hash_240000 lineitem_hash WHERE true GROUP BY l_orderkey ORDER BY (count(DISTINCT l_suppkey) FILTER (WHERE (l_shipmode OPERATOR(pg_catalog.=) 'AIR'::bpchar))) DESC, (count(DISTINCT l_suppkey)) DESC, l_orderkey LIMIT '10'::bigint
Node: host=localhost port=57637 dbname=regression
-> Limit
Output: l_orderkey, (count(DISTINCT l_suppkey) FILTER (WHERE (l_shipmode = 'AIR'::bpchar))), (count(DISTINCT l_suppkey))
@ -508,7 +515,7 @@ SELECT
Group Key: lineitem_hash.l_orderkey
-> Index Scan using lineitem_hash_pkey_240000 on public.lineitem_hash_240000 lineitem_hash
Output: l_orderkey, l_partkey, l_suppkey, l_linenumber, l_quantity, l_extendedprice, l_discount, l_tax, l_returnflag, l_linestatus, l_shipdate, l_commitdate, l_receiptdate, l_shipinstruct, l_shipmode, l_comment
(21 rows)
(22 rows)
-- group by on non-partition column
SELECT
@ -557,13 +564,14 @@ SELECT
Task Count: 8
Tasks Shown: One of 8
-> Task
Query: SELECT l_suppkey, l_partkey AS count, l_shipmode AS count FROM lineitem_hash_240000 lineitem_hash WHERE true GROUP BY l_suppkey, l_partkey, l_shipmode
Node: host=localhost port=57637 dbname=regression
-> HashAggregate
Output: l_suppkey, l_partkey, l_shipmode
Group Key: lineitem_hash.l_suppkey, lineitem_hash.l_partkey, lineitem_hash.l_shipmode
-> Seq Scan on public.lineitem_hash_240000 lineitem_hash
Output: l_orderkey, l_partkey, l_suppkey, l_linenumber, l_quantity, l_extendedprice, l_discount, l_tax, l_returnflag, l_linestatus, l_shipdate, l_commitdate, l_receiptdate, l_shipinstruct, l_shipmode, l_comment
(22 rows)
(23 rows)
-- without group by, on partition column
SELECT

View File

@ -96,6 +96,16 @@ EXPLAIN (COSTS off, ANALYZE on, TIMING off, SUMMARY off) SELECT count(*) FROM t1
END;
DROP TABLE t1, t2;
-- Test query text output, with ANALYZE ON
EXPLAIN (COSTS FALSE, ANALYZE TRUE, TIMING FALSE, SUMMARY FALSE, VERBOSE TRUE)
SELECT l_quantity, count(*) count_quantity FROM lineitem
GROUP BY l_quantity ORDER BY count_quantity, l_quantity;
-- Test query text output, with ANALYZE OFF
EXPLAIN (COSTS FALSE, ANALYZE FALSE, TIMING FALSE, SUMMARY FALSE, VERBOSE TRUE)
SELECT l_quantity, count(*) count_quantity FROM lineitem
GROUP BY l_quantity ORDER BY count_quantity, l_quantity;
-- Test verbose
EXPLAIN (COSTS FALSE, VERBOSE TRUE)
SELECT sum(l_quantity) / avg(l_quantity) FROM lineitem;