|
|
|
@ -1904,6 +1904,143 @@ RETURNING k, v; |
|
|
|
|
(0 rows) |
|
|
|
|
|
|
|
|
|
DROP TABLE withz; |
|
|
|
|
-- WITH referenced by MERGE statement |
|
|
|
|
CREATE TABLE m AS SELECT i AS k, (i || ' v')::text v FROM generate_series(1, 16, 3) i; |
|
|
|
|
ALTER TABLE m ADD UNIQUE (k); |
|
|
|
|
WITH RECURSIVE cte_basic AS (SELECT 1 a, 'cte_basic val' b) |
|
|
|
|
MERGE INTO m USING (select 0 k, 'merge source SubPlan' v) o ON m.k=o.k |
|
|
|
|
WHEN MATCHED THEN UPDATE SET v = (SELECT b || ' merge update' FROM cte_basic WHERE cte_basic.a = m.k LIMIT 1) |
|
|
|
|
WHEN NOT MATCHED THEN INSERT VALUES(o.k, o.v); |
|
|
|
|
ERROR: WITH RECURSIVE is not supported for MERGE statement |
|
|
|
|
-- Basic: |
|
|
|
|
WITH cte_basic AS (SELECT 1 a, 'cte_basic val' b) |
|
|
|
|
MERGE INTO m USING (select 0 k, 'merge source SubPlan' v) o ON m.k=o.k |
|
|
|
|
WHEN MATCHED THEN UPDATE SET v = (SELECT b || ' merge update' FROM cte_basic WHERE cte_basic.a = m.k LIMIT 1) |
|
|
|
|
WHEN NOT MATCHED THEN INSERT VALUES(o.k, o.v); |
|
|
|
|
-- Examine |
|
|
|
|
SELECT * FROM m where k = 0; |
|
|
|
|
k | v |
|
|
|
|
---+---------------------- |
|
|
|
|
0 | merge source SubPlan |
|
|
|
|
(1 row) |
|
|
|
|
|
|
|
|
|
-- See EXPLAIN output for same query: |
|
|
|
|
EXPLAIN (VERBOSE, COSTS OFF) |
|
|
|
|
WITH cte_basic AS (SELECT 1 a, 'cte_basic val' b) |
|
|
|
|
MERGE INTO m USING (select 0 k, 'merge source SubPlan' v) o ON m.k=o.k |
|
|
|
|
WHEN MATCHED THEN UPDATE SET v = (SELECT b || ' merge update' FROM cte_basic WHERE cte_basic.a = m.k LIMIT 1) |
|
|
|
|
WHEN NOT MATCHED THEN INSERT VALUES(o.k, o.v); |
|
|
|
|
QUERY PLAN |
|
|
|
|
------------------------------------------------------------------- |
|
|
|
|
Merge on public.m |
|
|
|
|
CTE cte_basic |
|
|
|
|
-> Result |
|
|
|
|
Output: 1, 'cte_basic val'::text |
|
|
|
|
-> Hash Right Join |
|
|
|
|
Output: o.k, o.v, o.*, m_1.ctid |
|
|
|
|
Hash Cond: (m_1.k = o.k) |
|
|
|
|
-> Seq Scan on public.m m_1 |
|
|
|
|
Output: m_1.ctid, m_1.k |
|
|
|
|
-> Hash |
|
|
|
|
Output: o.k, o.v, o.* |
|
|
|
|
-> Subquery Scan on o |
|
|
|
|
Output: o.k, o.v, o.* |
|
|
|
|
-> Result |
|
|
|
|
Output: 0, 'merge source SubPlan'::text |
|
|
|
|
SubPlan 2 |
|
|
|
|
-> Limit |
|
|
|
|
Output: ((cte_basic.b || ' merge update'::text)) |
|
|
|
|
-> CTE Scan on cte_basic |
|
|
|
|
Output: (cte_basic.b || ' merge update'::text) |
|
|
|
|
Filter: (cte_basic.a = m.k) |
|
|
|
|
(21 rows) |
|
|
|
|
|
|
|
|
|
-- InitPlan |
|
|
|
|
WITH cte_init AS (SELECT 1 a, 'cte_init val' b) |
|
|
|
|
MERGE INTO m USING (select 1 k, 'merge source InitPlan' v) o ON m.k=o.k |
|
|
|
|
WHEN MATCHED THEN UPDATE SET v = (SELECT b || ' merge update' FROM cte_init WHERE a = 1 LIMIT 1) |
|
|
|
|
WHEN NOT MATCHED THEN INSERT VALUES(o.k, o.v); |
|
|
|
|
-- Examine |
|
|
|
|
SELECT * FROM m where k = 1; |
|
|
|
|
k | v |
|
|
|
|
---+--------------------------- |
|
|
|
|
1 | cte_init val merge update |
|
|
|
|
(1 row) |
|
|
|
|
|
|
|
|
|
-- See EXPLAIN output for same query: |
|
|
|
|
EXPLAIN (VERBOSE, COSTS OFF) |
|
|
|
|
WITH cte_init AS (SELECT 1 a, 'cte_init val' b) |
|
|
|
|
MERGE INTO m USING (select 1 k, 'merge source InitPlan' v) o ON m.k=o.k |
|
|
|
|
WHEN MATCHED THEN UPDATE SET v = (SELECT b || ' merge update' FROM cte_init WHERE a = 1 LIMIT 1) |
|
|
|
|
WHEN NOT MATCHED THEN INSERT VALUES(o.k, o.v); |
|
|
|
|
QUERY PLAN |
|
|
|
|
-------------------------------------------------------------------- |
|
|
|
|
Merge on public.m |
|
|
|
|
CTE cte_init |
|
|
|
|
-> Result |
|
|
|
|
Output: 1, 'cte_init val'::text |
|
|
|
|
InitPlan 2 (returns $1) |
|
|
|
|
-> Limit |
|
|
|
|
Output: ((cte_init.b || ' merge update'::text)) |
|
|
|
|
-> CTE Scan on cte_init |
|
|
|
|
Output: (cte_init.b || ' merge update'::text) |
|
|
|
|
Filter: (cte_init.a = 1) |
|
|
|
|
-> Hash Right Join |
|
|
|
|
Output: o.k, o.v, o.*, m_1.ctid |
|
|
|
|
Hash Cond: (m_1.k = o.k) |
|
|
|
|
-> Seq Scan on public.m m_1 |
|
|
|
|
Output: m_1.ctid, m_1.k |
|
|
|
|
-> Hash |
|
|
|
|
Output: o.k, o.v, o.* |
|
|
|
|
-> Subquery Scan on o |
|
|
|
|
Output: o.k, o.v, o.* |
|
|
|
|
-> Result |
|
|
|
|
Output: 1, 'merge source InitPlan'::text |
|
|
|
|
(21 rows) |
|
|
|
|
|
|
|
|
|
-- MERGE source comes from CTE: |
|
|
|
|
WITH merge_source_cte AS (SELECT 15 a, 'merge_source_cte val' b) |
|
|
|
|
MERGE INTO m USING (select * from merge_source_cte) o ON m.k=o.a |
|
|
|
|
WHEN MATCHED THEN UPDATE SET v = (SELECT b || merge_source_cte.*::text || ' merge update' FROM merge_source_cte WHERE a = 15) |
|
|
|
|
WHEN NOT MATCHED THEN INSERT VALUES(o.a, o.b || (SELECT merge_source_cte.*::text || ' merge insert' FROM merge_source_cte)); |
|
|
|
|
-- Examine |
|
|
|
|
SELECT * FROM m where k = 15; |
|
|
|
|
k | v |
|
|
|
|
----+-------------------------------------------------------------- |
|
|
|
|
15 | merge_source_cte val(15,"merge_source_cte val") merge insert |
|
|
|
|
(1 row) |
|
|
|
|
|
|
|
|
|
-- See EXPLAIN output for same query: |
|
|
|
|
EXPLAIN (VERBOSE, COSTS OFF) |
|
|
|
|
WITH merge_source_cte AS (SELECT 15 a, 'merge_source_cte val' b) |
|
|
|
|
MERGE INTO m USING (select * from merge_source_cte) o ON m.k=o.a |
|
|
|
|
WHEN MATCHED THEN UPDATE SET v = (SELECT b || merge_source_cte.*::text || ' merge update' FROM merge_source_cte WHERE a = 15) |
|
|
|
|
WHEN NOT MATCHED THEN INSERT VALUES(o.a, o.b || (SELECT merge_source_cte.*::text || ' merge insert' FROM merge_source_cte)); |
|
|
|
|
QUERY PLAN |
|
|
|
|
--------------------------------------------------------------------------------------------------------------- |
|
|
|
|
Merge on public.m |
|
|
|
|
CTE merge_source_cte |
|
|
|
|
-> Result |
|
|
|
|
Output: 15, 'merge_source_cte val'::text |
|
|
|
|
InitPlan 2 (returns $1) |
|
|
|
|
-> CTE Scan on merge_source_cte merge_source_cte_1 |
|
|
|
|
Output: ((merge_source_cte_1.b || (merge_source_cte_1.*)::text) || ' merge update'::text) |
|
|
|
|
Filter: (merge_source_cte_1.a = 15) |
|
|
|
|
InitPlan 3 (returns $2) |
|
|
|
|
-> CTE Scan on merge_source_cte merge_source_cte_2 |
|
|
|
|
Output: ((merge_source_cte_2.*)::text || ' merge insert'::text) |
|
|
|
|
-> Hash Right Join |
|
|
|
|
Output: merge_source_cte.a, merge_source_cte.b, ROW(merge_source_cte.a, merge_source_cte.b), m_1.ctid |
|
|
|
|
Hash Cond: (m_1.k = merge_source_cte.a) |
|
|
|
|
-> Seq Scan on public.m m_1 |
|
|
|
|
Output: m_1.ctid, m_1.k |
|
|
|
|
-> Hash |
|
|
|
|
Output: merge_source_cte.a, merge_source_cte.b |
|
|
|
|
-> CTE Scan on merge_source_cte |
|
|
|
|
Output: merge_source_cte.a, merge_source_cte.b |
|
|
|
|
(20 rows) |
|
|
|
|
|
|
|
|
|
DROP TABLE m; |
|
|
|
|
-- check that run to completion happens in proper ordering |
|
|
|
|
TRUNCATE TABLE y; |
|
|
|
|
INSERT INTO y SELECT generate_series(1, 3); |
|
|
|
|