|
| 1 | +/* |
| 2 | + * Test simple CTE queries. |
| 3 | + * Since 12 (608b167f9f), CTEs which are scanned once are no longer an |
| 4 | + * optimization fence, which changes practically all plans here. There is |
| 5 | + * an option to forcibly make them MATERIALIZED, but we also need to run tests |
| 6 | + * on older versions, so create pathman_cte_1.out instead. |
| 7 | + */ |
| 8 | +\set VERBOSITY terse |
| 9 | +SET search_path = 'public'; |
| 10 | +CREATE EXTENSION pg_pathman; |
| 11 | +CREATE SCHEMA test_cte; |
| 12 | +CREATE TABLE test_cte.range_rel ( |
| 13 | + id INT4, |
| 14 | + dt TIMESTAMP NOT NULL, |
| 15 | + txt TEXT); |
| 16 | +INSERT INTO test_cte.range_rel (dt, txt) |
| 17 | +SELECT g, md5(g::TEXT) |
| 18 | +FROM generate_series('2015-01-01', '2015-04-30', '1 day'::interval) AS g; |
| 19 | +SELECT create_range_partitions('test_cte.range_rel', 'DT', '2015-01-01'::DATE, '1 month'::INTERVAL); |
| 20 | + create_range_partitions |
| 21 | +------------------------- |
| 22 | + 4 |
| 23 | +(1 row) |
| 24 | + |
| 25 | +/* perform a query */ |
| 26 | +EXPLAIN (COSTS OFF) |
| 27 | + WITH ttt AS (SELECT * FROM test_cte.range_rel WHERE dt >= '2015-02-01' AND dt < '2015-03-15') |
| 28 | +SELECT * FROM ttt; |
| 29 | + QUERY PLAN |
| 30 | +-------------------------------------------------------------------------------- |
| 31 | + Append |
| 32 | + -> Seq Scan on range_rel_2 |
| 33 | + -> Seq Scan on range_rel_3 |
| 34 | + Filter: (dt < 'Sun Mar 15 00:00:00 2015'::timestamp without time zone) |
| 35 | +(4 rows) |
| 36 | + |
| 37 | +DROP TABLE test_cte.range_rel CASCADE; |
| 38 | +NOTICE: drop cascades to 5 other objects |
| 39 | +CREATE TABLE test_cte.hash_rel ( |
| 40 | + id INT4, |
| 41 | + value INTEGER NOT NULL); |
| 42 | +INSERT INTO test_cte.hash_rel VALUES (1, 1); |
| 43 | +INSERT INTO test_cte.hash_rel VALUES (2, 2); |
| 44 | +INSERT INTO test_cte.hash_rel VALUES (3, 3); |
| 45 | +SELECT create_hash_partitions('test_cte.hash_rel', 'value', 3); |
| 46 | + create_hash_partitions |
| 47 | +------------------------ |
| 48 | + 3 |
| 49 | +(1 row) |
| 50 | + |
| 51 | +/* perform a query */ |
| 52 | +EXPLAIN (COSTS OFF) |
| 53 | + WITH ttt AS (SELECT * FROM test_cte.hash_rel WHERE value = 2) |
| 54 | +SELECT * FROM ttt; |
| 55 | + QUERY PLAN |
| 56 | +------------------------ |
| 57 | + Seq Scan on hash_rel_1 |
| 58 | + Filter: (value = 2) |
| 59 | +(2 rows) |
| 60 | + |
| 61 | +DROP TABLE test_cte.hash_rel CASCADE; |
| 62 | +NOTICE: drop cascades to 3 other objects |
| 63 | +/* |
| 64 | + * Test CTE query - by @parihaaraka (add varno to WalkerContext) |
| 65 | + */ |
| 66 | +CREATE TABLE test_cte.cte_del_xacts (id BIGSERIAL PRIMARY KEY, pdate DATE NOT NULL); |
| 67 | +INSERT INTO test_cte.cte_del_xacts (pdate) |
| 68 | +SELECT gen_date |
| 69 | +FROM generate_series('2016-01-01'::date, '2016-04-9'::date, '1 day') AS gen_date; |
| 70 | +CREATE TABLE test_cte.cte_del_xacts_specdata |
| 71 | +( |
| 72 | + tid BIGINT PRIMARY KEY, |
| 73 | + test_mode SMALLINT, |
| 74 | + state_code SMALLINT NOT NULL DEFAULT 8, |
| 75 | + regtime TIMESTAMP WITHOUT TIME ZONE NOT NULL |
| 76 | +); |
| 77 | +INSERT INTO test_cte.cte_del_xacts_specdata VALUES (1, 1, 1, current_timestamp); /* for subquery test */ |
| 78 | +/* create 2 partitions */ |
| 79 | +SELECT create_range_partitions('test_cte.cte_del_xacts'::regclass, 'pdate', |
| 80 | + '2016-01-01'::date, '50 days'::interval); |
| 81 | + create_range_partitions |
| 82 | +------------------------- |
| 83 | + 2 |
| 84 | +(1 row) |
| 85 | + |
| 86 | +EXPLAIN (COSTS OFF) |
| 87 | +WITH tmp AS ( |
| 88 | + SELECT tid, test_mode, regtime::DATE AS pdate, state_code |
| 89 | + FROM test_cte.cte_del_xacts_specdata) |
| 90 | +DELETE FROM test_cte.cte_del_xacts t USING tmp |
| 91 | +WHERE t.id = tmp.tid AND t.pdate = tmp.pdate AND tmp.test_mode > 0; |
| 92 | + QUERY PLAN |
| 93 | +----------------------------------------------------------------------------------------------------------------- |
| 94 | + Delete on cte_del_xacts t |
| 95 | + Delete on cte_del_xacts t_1 |
| 96 | + Delete on cte_del_xacts_1 t_2 |
| 97 | + Delete on cte_del_xacts_2 t_3 |
| 98 | + -> Hash Join |
| 99 | + Hash Cond: ((t.id = cte_del_xacts_specdata.tid) AND (t.pdate = (cte_del_xacts_specdata.regtime)::date)) |
| 100 | + -> Append |
| 101 | + -> Seq Scan on cte_del_xacts t_1 |
| 102 | + -> Seq Scan on cte_del_xacts_1 t_2 |
| 103 | + -> Seq Scan on cte_del_xacts_2 t_3 |
| 104 | + -> Hash |
| 105 | + -> Seq Scan on cte_del_xacts_specdata |
| 106 | + Filter: (test_mode > 0) |
| 107 | +(13 rows) |
| 108 | + |
| 109 | +SELECT drop_partitions('test_cte.cte_del_xacts'); /* now drop partitions */ |
| 110 | +NOTICE: 50 rows copied from test_cte.cte_del_xacts_1 |
| 111 | +NOTICE: 50 rows copied from test_cte.cte_del_xacts_2 |
| 112 | + drop_partitions |
| 113 | +----------------- |
| 114 | + 2 |
| 115 | +(1 row) |
| 116 | + |
| 117 | +/* create 1 partition */ |
| 118 | +SELECT create_range_partitions('test_cte.cte_del_xacts'::regclass, 'pdate', |
| 119 | + '2016-01-01'::date, '1 year'::interval); |
| 120 | + create_range_partitions |
| 121 | +------------------------- |
| 122 | + 1 |
| 123 | +(1 row) |
| 124 | + |
| 125 | +/* parent enabled! */ |
| 126 | +SELECT set_enable_parent('test_cte.cte_del_xacts', true); |
| 127 | + set_enable_parent |
| 128 | +------------------- |
| 129 | + |
| 130 | +(1 row) |
| 131 | + |
| 132 | +EXPLAIN (COSTS OFF) |
| 133 | +WITH tmp AS ( |
| 134 | + SELECT tid, test_mode, regtime::DATE AS pdate, state_code |
| 135 | + FROM test_cte.cte_del_xacts_specdata) |
| 136 | +DELETE FROM test_cte.cte_del_xacts t USING tmp |
| 137 | +WHERE t.id = tmp.tid AND t.pdate = tmp.pdate AND tmp.test_mode > 0; |
| 138 | + QUERY PLAN |
| 139 | +----------------------------------------------------------------------------------------------------------------- |
| 140 | + Delete on cte_del_xacts t |
| 141 | + Delete on cte_del_xacts t_1 |
| 142 | + Delete on cte_del_xacts_1 t_2 |
| 143 | + -> Hash Join |
| 144 | + Hash Cond: ((t.id = cte_del_xacts_specdata.tid) AND (t.pdate = (cte_del_xacts_specdata.regtime)::date)) |
| 145 | + -> Append |
| 146 | + -> Seq Scan on cte_del_xacts t_1 |
| 147 | + -> Seq Scan on cte_del_xacts_1 t_2 |
| 148 | + -> Hash |
| 149 | + -> Seq Scan on cte_del_xacts_specdata |
| 150 | + Filter: (test_mode > 0) |
| 151 | +(11 rows) |
| 152 | + |
| 153 | +/* parent disabled! */ |
| 154 | +SELECT set_enable_parent('test_cte.cte_del_xacts', false); |
| 155 | + set_enable_parent |
| 156 | +------------------- |
| 157 | + |
| 158 | +(1 row) |
| 159 | + |
| 160 | +EXPLAIN (COSTS OFF) |
| 161 | +WITH tmp AS ( |
| 162 | + SELECT tid, test_mode, regtime::DATE AS pdate, state_code |
| 163 | + FROM test_cte.cte_del_xacts_specdata) |
| 164 | +DELETE FROM test_cte.cte_del_xacts t USING tmp |
| 165 | +WHERE t.id = tmp.tid AND t.pdate = tmp.pdate AND tmp.test_mode > 0; |
| 166 | + QUERY PLAN |
| 167 | +----------------------------------------------------------------------------------------------------------------- |
| 168 | + Delete on cte_del_xacts_1 t |
| 169 | + -> Hash Join |
| 170 | + Hash Cond: ((t.id = cte_del_xacts_specdata.tid) AND (t.pdate = (cte_del_xacts_specdata.regtime)::date)) |
| 171 | + -> Seq Scan on cte_del_xacts_1 t |
| 172 | + -> Hash |
| 173 | + -> Seq Scan on cte_del_xacts_specdata |
| 174 | + Filter: (test_mode > 0) |
| 175 | +(7 rows) |
| 176 | + |
| 177 | +/* create stub pl/PgSQL function */ |
| 178 | +CREATE OR REPLACE FUNCTION test_cte.cte_del_xacts_stab(name TEXT) |
| 179 | +RETURNS smallint AS |
| 180 | +$$ |
| 181 | +begin |
| 182 | + return 2::smallint; |
| 183 | +end |
| 184 | +$$ |
| 185 | +LANGUAGE plpgsql STABLE; |
| 186 | +/* test subquery planning */ |
| 187 | +WITH tmp AS ( |
| 188 | + SELECT tid FROM test_cte.cte_del_xacts_specdata |
| 189 | + WHERE state_code != test_cte.cte_del_xacts_stab('test')) |
| 190 | +SELECT * FROM test_cte.cte_del_xacts t JOIN tmp ON t.id = tmp.tid; |
| 191 | + id | pdate | tid |
| 192 | +----+------------+----- |
| 193 | + 1 | 01-01-2016 | 1 |
| 194 | +(1 row) |
| 195 | + |
| 196 | +/* test subquery planning (one more time) */ |
| 197 | +WITH tmp AS ( |
| 198 | + SELECT tid FROM test_cte.cte_del_xacts_specdata |
| 199 | + WHERE state_code != test_cte.cte_del_xacts_stab('test')) |
| 200 | +SELECT * FROM test_cte.cte_del_xacts t JOIN tmp ON t.id = tmp.tid; |
| 201 | + id | pdate | tid |
| 202 | +----+------------+----- |
| 203 | + 1 | 01-01-2016 | 1 |
| 204 | +(1 row) |
| 205 | + |
| 206 | +DROP FUNCTION test_cte.cte_del_xacts_stab(TEXT); |
| 207 | +DROP TABLE test_cte.cte_del_xacts, test_cte.cte_del_xacts_specdata CASCADE; |
| 208 | +NOTICE: drop cascades to 2 other objects |
| 209 | +/* Test recursive CTE */ |
| 210 | +CREATE TABLE test_cte.recursive_cte_test_tbl(id INT NOT NULL, name TEXT NOT NULL); |
| 211 | +SELECT create_hash_partitions('test_cte.recursive_cte_test_tbl', 'id', 2); |
| 212 | + create_hash_partitions |
| 213 | +------------------------ |
| 214 | + 2 |
| 215 | +(1 row) |
| 216 | + |
| 217 | +INSERT INTO test_cte.recursive_cte_test_tbl (id, name) |
| 218 | +SELECT id, 'name'||id FROM generate_series(1,100) f(id); |
| 219 | +INSERT INTO test_cte.recursive_cte_test_tbl (id, name) |
| 220 | +SELECT id, 'name'||(id + 1) FROM generate_series(1,100) f(id); |
| 221 | +INSERT INTO test_cte.recursive_cte_test_tbl (id, name) |
| 222 | +SELECT id, 'name'||(id + 2) FROM generate_series(1,100) f(id); |
| 223 | +SELECT * FROM test_cte.recursive_cte_test_tbl WHERE id = 5; |
| 224 | + id | name |
| 225 | +----+------- |
| 226 | + 5 | name5 |
| 227 | + 5 | name6 |
| 228 | + 5 | name7 |
| 229 | +(3 rows) |
| 230 | + |
| 231 | +WITH RECURSIVE test AS ( |
| 232 | + SELECT min(name) AS name |
| 233 | + FROM test_cte.recursive_cte_test_tbl |
| 234 | + WHERE id = 5 |
| 235 | + UNION ALL |
| 236 | + SELECT (SELECT min(name) |
| 237 | + FROM test_cte.recursive_cte_test_tbl |
| 238 | + WHERE id = 5 AND name > test.name) |
| 239 | + FROM test |
| 240 | + WHERE name IS NOT NULL) |
| 241 | +SELECT * FROM test; |
| 242 | + name |
| 243 | +------- |
| 244 | + name5 |
| 245 | + name6 |
| 246 | + name7 |
| 247 | + |
| 248 | +(4 rows) |
| 249 | + |
| 250 | +DROP SCHEMA test_cte CASCADE; |
| 251 | +NOTICE: drop cascades to 3 other objects |
| 252 | +DROP EXTENSION pg_pathman; |
0 commit comments