Skip to content
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

ADBDEV-5527: Explain Analyze doesn't show statistics for queries with DML inside CTE #1174

Merged
merged 3 commits into from
Jan 16, 2025
Merged
Show file tree
Hide file tree
Changes from 1 commit
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
10 changes: 7 additions & 3 deletions src/backend/tcop/pquery.c
Original file line number Diff line number Diff line change
Expand Up @@ -357,6 +357,9 @@ ChoosePortalStrategy(List *stmts)
/* Note For CreateTableAs, we still use PORTAL_MULTI_QUERY (not like PG)
* since QE needs to use DestRemote to deliver completionTag to QD and
* use DestIntoRel to insert tuples into the table(s).
*
* For modifying CTE we use PORTAL_MULTI_QUERY at QE nodes, because
* we don't need saving the result inside portal's tuple store.
*/
if (list_length(stmts) == 1)
{
Expand Down Expand Up @@ -396,10 +399,11 @@ ChoosePortalStrategy(List *stmts)
pstmt->copyIntoClause == NULL &&
pstmt->refreshClause == NULL)
{
if (pstmt->hasModifyingCTE)
return PORTAL_ONE_MOD_WITH;
else
if (!pstmt->hasModifyingCTE)
return PORTAL_ONE_SELECT;
if (Gp_role != GP_ROLE_EXECUTE)
bimboterminator1 marked this conversation as resolved.
Show resolved Hide resolved
return PORTAL_ONE_MOD_WITH;
return PORTAL_MULTI_QUERY;
}
if (pstmt->commandType == CMD_UTILITY)
{
Expand Down
72 changes: 72 additions & 0 deletions src/test/regress/expected/explain_analyze.out
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,8 @@
-- s/Planning Time: [0-9.]+ ms/Planning Time: #.### ms/
-- m/Execution Time: [0-9.]+ ms/
-- s/Execution Time: [0-9.]+ ms/Execution Time: #.### ms/
-- m/Executor memory: \d+\w? bytes \(seg\d+\)/
-- s/Executor memory: \d+\w? bytes \(seg\d+\)/Executor memory: ### bytes (seg#)/
-- m/Executor memory: \d+\w? bytes/
-- s/Executor memory: \d+\w? bytes/Executor memory: ### bytes/
-- m/Memory used:\s+\d+\w?B/
Expand Down Expand Up @@ -150,3 +152,73 @@ explain (analyze, timing off, costs off)
-- explain_processing_on
drop table slice_test;
drop table slice_test2;
-- The statistics for modifying CTEs used to be reported as "never executed",
-- when all plan nodes were executed and some stat information was expected.
-- Test QD recieving the stats from all slices and showing it in explain output.
--start_ignore
DROP TABLE IF EXISTS with_dml;
NOTICE: table "with_dml" does not exist, skipping
--end_ignore
CREATE TABLE with_dml (i int, j int) DISTRIBUTED BY (i);
EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF)
WITH cte AS (
INSERT INTO with_dml SELECT i, i * 100 FROM generate_series(1,5) i
RETURNING i
) SELECT * FROM cte;
QUERY PLAN
-----------------------------------------------------------------------------------------------------------
Gather Motion 3:1 (slice1; segments: 3) (actual rows=5 loops=1)
-> Shared Scan (share slice:id 1:0) (actual rows=3 loops=1)
-> Insert on with_dml (actual rows=3 loops=1)
-> Redistribute Motion 1:3 (slice2; segments: 1) (actual rows=3 loops=1)
Hash Key: i.i
-> Function Scan on generate_series i (actual rows=5 loops=1)
Optimizer: Postgres-based planner
Planning Time: 0.163 ms
(slice0) Executor memory: 36K bytes.
(slice1) Executor memory: 36K bytes avg x 3 workers, 36K bytes max (seg0). Work_mem: 17K bytes max.
(slice2) Executor memory: 40K bytes (seg2). Work_mem: 17K bytes max.
Memory used: 256000kB
Execution Time: 7.189 ms
(13 rows)

EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF)
WITH cte AS (
UPDATE with_dml SET j = j + 1
RETURNING i
) SELECT * FROM cte;
QUERY PLAN
-----------------------------------------------------------------------------------------------------------
Gather Motion 3:1 (slice1; segments: 3) (actual rows=5 loops=1)
-> Shared Scan (share slice:id 1:0) (actual rows=3 loops=1)
-> Update on with_dml (actual rows=3 loops=1)
-> Seq Scan on with_dml (actual rows=3 loops=1)
Optimizer: Postgres-based planner
Planning Time: 0.288 ms
(slice0) Executor memory: 38K bytes.
(slice1) Executor memory: 38K bytes avg x 3 workers, 38K bytes max (seg0). Work_mem: 17K bytes max.
Memory used: 256000kB
Execution Time: 1.290 ms
(10 rows)

EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF)
WITH cte AS (
DELETE FROM with_dml WHERE i > 0
RETURNING i
) SELECT * FROM cte;
QUERY PLAN
-----------------------------------------------------------------------------------------------------------
Gather Motion 3:1 (slice1; segments: 3) (actual rows=5 loops=1)
-> Shared Scan (share slice:id 1:0) (actual rows=3 loops=1)
-> Delete on with_dml (actual rows=3 loops=1)
-> Seq Scan on with_dml (actual rows=3 loops=1)
Filter: (i > 0)
Optimizer: Postgres-based planner
Planning Time: 0.232 ms
(slice0) Executor memory: 38K bytes.
(slice1) Executor memory: 37K bytes avg x 3 workers, 37K bytes max (seg0). Work_mem: 17K bytes max.
Memory used: 256000kB
Execution Time: 0.947 ms
(11 rows)

DROP TABLE with_dml;
72 changes: 72 additions & 0 deletions src/test/regress/expected/explain_analyze_optimizer.out
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,8 @@
-- s/Planning Time: [0-9.]+ ms/Planning Time: #.### ms/
-- m/Execution Time: [0-9.]+ ms/
-- s/Execution Time: [0-9.]+ ms/Execution Time: #.### ms/
-- m/Executor memory: \d+\w? bytes \(seg\d+\)/
-- s/Executor memory: \d+\w? bytes \(seg\d+\)/Executor memory: ### bytes (seg#)/
-- m/Executor memory: \d+\w? bytes/
-- s/Executor memory: \d+\w? bytes/Executor memory: ### bytes/
-- m/Memory used:\s+\d+\w?B/
Expand Down Expand Up @@ -153,3 +155,73 @@ explain (analyze, timing off, costs off)
-- explain_processing_on
drop table slice_test;
drop table slice_test2;
-- The statistics for modifying CTEs used to be reported as "never executed",
-- when all plan nodes were executed and some stat information was expected.
-- Test QD recieving the stats from all slices and showing it in explain output.
--start_ignore
DROP TABLE IF EXISTS with_dml;
NOTICE: table "with_dml" does not exist, skipping
--end_ignore
CREATE TABLE with_dml (i int, j int) DISTRIBUTED BY (i);
EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF)
WITH cte AS (
INSERT INTO with_dml SELECT i, i * 100 FROM generate_series(1,5) i
RETURNING i
) SELECT * FROM cte;
QUERY PLAN
-----------------------------------------------------------------------------------------------------------
Gather Motion 3:1 (slice1; segments: 3) (actual rows=5 loops=1)
-> Shared Scan (share slice:id 1:0) (actual rows=3 loops=1)
-> Insert on with_dml (actual rows=3 loops=1)
-> Redistribute Motion 1:3 (slice2; segments: 1) (actual rows=3 loops=1)
Hash Key: i.i
-> Function Scan on generate_series i (actual rows=5 loops=1)
Optimizer: Postgres-based planner
Planning Time: 2.969 ms
(slice0) Executor memory: 36K bytes.
(slice1) Executor memory: 36K bytes avg x 3 workers, 36K bytes max (seg0). Work_mem: 17K bytes max.
(slice2) Executor memory: 40K bytes (seg2). Work_mem: 17K bytes max.
Memory used: 256000kB
Execution Time: 7.598 ms
(13 rows)

EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF)
WITH cte AS (
UPDATE with_dml SET j = j + 1
RETURNING i
) SELECT * FROM cte;
QUERY PLAN
-----------------------------------------------------------------------------------------------------------
Gather Motion 3:1 (slice1; segments: 3) (actual rows=5 loops=1)
-> Shared Scan (share slice:id 1:0) (actual rows=3 loops=1)
-> Update on with_dml (actual rows=3 loops=1)
-> Seq Scan on with_dml (actual rows=3 loops=1)
Optimizer: Postgres-based planner
Planning Time: 2.896 ms
(slice0) Executor memory: 38K bytes.
(slice1) Executor memory: 38K bytes avg x 3 workers, 38K bytes max (seg0). Work_mem: 17K bytes max.
Memory used: 256000kB
Execution Time: 1.348 ms
(10 rows)

EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF)
WITH cte AS (
DELETE FROM with_dml WHERE i > 0
RETURNING i
) SELECT * FROM cte;
QUERY PLAN
-----------------------------------------------------------------------------------------------------------
Gather Motion 3:1 (slice1; segments: 3) (actual rows=5 loops=1)
-> Shared Scan (share slice:id 1:0) (actual rows=3 loops=1)
-> Delete on with_dml (actual rows=3 loops=1)
-> Seq Scan on with_dml (actual rows=3 loops=1)
Filter: (i > 0)
Optimizer: Postgres-based planner
Planning Time: 2.691 ms
(slice0) Executor memory: 38K bytes.
(slice1) Executor memory: 37K bytes avg x 3 workers, 37K bytes max (seg0). Work_mem: 17K bytes max.
Memory used: 256000kB
Execution Time: 1.059 ms
(11 rows)

DROP TABLE with_dml;
26 changes: 26 additions & 0 deletions src/test/regress/sql/explain_analyze.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,8 @@
-- s/Planning Time: [0-9.]+ ms/Planning Time: #.### ms/
-- m/Execution Time: [0-9.]+ ms/
-- s/Execution Time: [0-9.]+ ms/Execution Time: #.### ms/
-- m/Executor memory: \d+\w? bytes \(seg\d+\)/
-- s/Executor memory: \d+\w? bytes \(seg\d+\)/Executor memory: ### bytes (seg#)/
-- m/Executor memory: \d+\w? bytes/
-- s/Executor memory: \d+\w? bytes/Executor memory: ### bytes/
-- m/Memory used:\s+\d+\w?B/
Expand Down Expand Up @@ -76,3 +78,27 @@ explain (analyze, timing off, costs off)

drop table slice_test;
drop table slice_test2;

-- The statistics for modifying CTEs used to be reported as "never executed",
-- when all plan nodes were executed and some stat information was expected.
-- Test QD recieving the stats from all slices and showing it in explain output.
--start_ignore
DROP TABLE IF EXISTS with_dml;
--end_ignore
CREATE TABLE with_dml (i int, j int) DISTRIBUTED BY (i);
EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF)
WITH cte AS (
INSERT INTO with_dml SELECT i, i * 100 FROM generate_series(1,5) i
RETURNING i
) SELECT * FROM cte;
EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF)
WITH cte AS (
UPDATE with_dml SET j = j + 1
RETURNING i
) SELECT * FROM cte;
EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF)
WITH cte AS (
DELETE FROM with_dml WHERE i > 0
RETURNING i
) SELECT * FROM cte;
DROP TABLE with_dml;
Loading