mirror of https://github.com/citusdata/citus.git
Add some more tests with views to test recursive planning on views (#4427)
(cherry picked from commit 51f422f3c6
)
pull/4402/head^2
parent
49281202af
commit
cceaf31e4c
|
@ -3,6 +3,7 @@
|
|||
-- ===================================================================
|
||||
CREATE SCHEMA subquery_view;
|
||||
SET search_path TO subquery_view, public;
|
||||
SET citus.next_shard_id TO 1512000;
|
||||
CREATE TABLE users_table_local AS SELECT * FROM users_table;
|
||||
CREATE TABLE events_table_local AS SELECT * FROM events_table;
|
||||
SET client_min_messages TO DEBUG1;
|
||||
|
@ -560,8 +561,79 @@ DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT user_id, user
|
|||
(5 rows)
|
||||
|
||||
SET client_min_messages TO DEFAULT;
|
||||
CREATE TABLE reference_table (text_col text, int_col int);
|
||||
SELECT create_reference_table('reference_table');
|
||||
create_reference_table
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
EXPLAIN (COSTS OFF) WITH cte AS (
|
||||
SELECT application_name AS text_col
|
||||
FROM pg_stat_activity
|
||||
) SELECT * FROM reference_table JOIN cte USING (text_col);
|
||||
QUERY PLAN
|
||||
---------------------------------------------------------------------
|
||||
Custom Scan (Citus Adaptive)
|
||||
-> Distributed Subplan XXX_1
|
||||
-> Function Scan on pg_stat_get_activity s
|
||||
-> Distributed Subplan XXX_2
|
||||
-> Custom Scan (Citus Adaptive)
|
||||
Task Count: 1
|
||||
Tasks Shown: All
|
||||
-> Task
|
||||
Node: host=localhost port=xxxxx dbname=regression
|
||||
-> Hash Left Join
|
||||
Hash Cond: (intermediate_result.usesysid = u.oid)
|
||||
-> Hash Left Join
|
||||
Hash Cond: (intermediate_result.datid = d.oid)
|
||||
-> Function Scan on read_intermediate_result intermediate_result
|
||||
-> Hash
|
||||
-> Seq Scan on pg_database d
|
||||
-> Hash
|
||||
-> Seq Scan on pg_authid u
|
||||
Task Count: 1
|
||||
Tasks Shown: All
|
||||
-> Task
|
||||
Node: host=localhost port=xxxxx dbname=regression
|
||||
-> Merge Join
|
||||
Merge Cond: (intermediate_result.application_name = reference_table.text_col)
|
||||
-> Sort
|
||||
Sort Key: intermediate_result.application_name
|
||||
-> Function Scan on read_intermediate_result intermediate_result
|
||||
-> Sort
|
||||
Sort Key: reference_table.text_col
|
||||
-> Seq Scan on reference_table_1512000 reference_table
|
||||
(30 rows)
|
||||
|
||||
CREATE OR REPLACE VIEW view_on_views AS SELECT pg_stat_activity.application_name, pg_locks.pid FROM pg_stat_activity, pg_locks;
|
||||
EXPLAIN (COSTS OFF) WITH cte AS (
|
||||
SELECT application_name AS text_col
|
||||
FROM view_on_views
|
||||
) SELECT * FROM reference_table JOIN cte USING (text_col);
|
||||
QUERY PLAN
|
||||
---------------------------------------------------------------------
|
||||
Custom Scan (Citus Adaptive)
|
||||
-> Distributed Subplan XXX_1
|
||||
-> Nested Loop
|
||||
-> Function Scan on pg_stat_get_activity s
|
||||
-> Function Scan on pg_lock_status l
|
||||
Task Count: 1
|
||||
Tasks Shown: All
|
||||
-> Task
|
||||
Node: host=localhost port=xxxxx dbname=regression
|
||||
-> Merge Join
|
||||
Merge Cond: (intermediate_result.text_col = reference_table.text_col)
|
||||
-> Sort
|
||||
Sort Key: intermediate_result.text_col
|
||||
-> Function Scan on read_intermediate_result intermediate_result
|
||||
-> Sort
|
||||
Sort Key: reference_table.text_col
|
||||
-> Seq Scan on reference_table_1512000 reference_table
|
||||
(17 rows)
|
||||
|
||||
DROP SCHEMA subquery_view CASCADE;
|
||||
NOTICE: drop cascades to 17 other objects
|
||||
NOTICE: drop cascades to 19 other objects
|
||||
DETAIL: drop cascades to table users_table_local
|
||||
drop cascades to table events_table_local
|
||||
drop cascades to view view_without_subquery
|
||||
|
@ -579,4 +651,6 @@ drop cascades to view subquery_and_ctes
|
|||
drop cascades to view subquery_and_ctes_second
|
||||
drop cascades to view deep_subquery
|
||||
drop cascades to view result_of_view_is_also_recursively_planned
|
||||
drop cascades to table reference_table
|
||||
drop cascades to view view_on_views
|
||||
SET search_path TO public;
|
||||
|
|
|
@ -5,6 +5,7 @@
|
|||
CREATE SCHEMA subquery_view;
|
||||
SET search_path TO subquery_view, public;
|
||||
|
||||
SET citus.next_shard_id TO 1512000;
|
||||
|
||||
CREATE TABLE users_table_local AS SELECT * FROM users_table;
|
||||
CREATE TABLE events_table_local AS SELECT * FROM events_table;
|
||||
|
@ -426,5 +427,20 @@ ORDER BY time DESC LIMIT 5;
|
|||
|
||||
SET client_min_messages TO DEFAULT;
|
||||
|
||||
CREATE TABLE reference_table (text_col text, int_col int);
|
||||
SELECT create_reference_table('reference_table');
|
||||
|
||||
EXPLAIN (COSTS OFF) WITH cte AS (
|
||||
SELECT application_name AS text_col
|
||||
FROM pg_stat_activity
|
||||
) SELECT * FROM reference_table JOIN cte USING (text_col);
|
||||
|
||||
CREATE OR REPLACE VIEW view_on_views AS SELECT pg_stat_activity.application_name, pg_locks.pid FROM pg_stat_activity, pg_locks;
|
||||
|
||||
EXPLAIN (COSTS OFF) WITH cte AS (
|
||||
SELECT application_name AS text_col
|
||||
FROM view_on_views
|
||||
) SELECT * FROM reference_table JOIN cte USING (text_col);
|
||||
|
||||
DROP SCHEMA subquery_view CASCADE;
|
||||
SET search_path TO public;
|
||||
|
|
Loading…
Reference in New Issue