2008-10-04 17:56:55 -04:00
|
|
|
--
|
|
|
|
|
-- Tests for common table expressions (WITH query, ... SELECT ...)
|
|
|
|
|
--
|
|
|
|
|
|
|
|
|
|
-- Basic WITH
|
|
|
|
|
WITH q1(x,y) AS (SELECT 1,2)
|
|
|
|
|
SELECT * FROM q1, q1 AS q2;
|
|
|
|
|
|
|
|
|
|
-- Multiple uses are evaluated only once
|
|
|
|
|
SELECT count(*) FROM (
|
|
|
|
|
WITH q1(x) AS (SELECT random() FROM generate_series(1, 5))
|
|
|
|
|
SELECT * FROM q1
|
|
|
|
|
UNION
|
|
|
|
|
SELECT * FROM q1
|
|
|
|
|
) ss;
|
|
|
|
|
|
|
|
|
|
-- WITH RECURSIVE
|
|
|
|
|
|
|
|
|
|
-- sum of 1..100
|
|
|
|
|
WITH RECURSIVE t(n) AS (
|
|
|
|
|
VALUES (1)
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT n+1 FROM t WHERE n < 100
|
|
|
|
|
)
|
|
|
|
|
SELECT sum(n) FROM t;
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE t(n) AS (
|
|
|
|
|
SELECT (VALUES(1))
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT n+1 FROM t WHERE n < 5
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM t;
|
|
|
|
|
|
2020-11-18 01:58:37 -05:00
|
|
|
-- UNION DISTINCT requires hashable type
|
|
|
|
|
WITH RECURSIVE t(n) AS (
|
|
|
|
|
VALUES (1::money)
|
|
|
|
|
UNION
|
|
|
|
|
SELECT n+1::money FROM t WHERE n < 100::money
|
|
|
|
|
)
|
|
|
|
|
SELECT sum(n) FROM t;
|
|
|
|
|
|
2013-01-31 22:31:58 -05:00
|
|
|
-- recursive view
|
|
|
|
|
CREATE RECURSIVE VIEW nums (n) AS
|
|
|
|
|
VALUES (1)
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT n+1 FROM nums WHERE n < 5;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM nums;
|
|
|
|
|
|
|
|
|
|
CREATE OR REPLACE RECURSIVE VIEW nums (n) AS
|
|
|
|
|
VALUES (1)
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT n+1 FROM nums WHERE n < 6;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM nums;
|
|
|
|
|
|
2008-10-07 15:27:04 -04:00
|
|
|
-- This is an infinite loop with UNION ALL, but not with UNION
|
|
|
|
|
WITH RECURSIVE t(n) AS (
|
|
|
|
|
SELECT 1
|
|
|
|
|
UNION
|
|
|
|
|
SELECT 10-n FROM t)
|
|
|
|
|
SELECT * FROM t;
|
|
|
|
|
|
2008-10-04 17:56:55 -04:00
|
|
|
-- This'd be an infinite loop, but outside query reads only as much as needed
|
|
|
|
|
WITH RECURSIVE t(n) AS (
|
|
|
|
|
VALUES (1)
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT n+1 FROM t)
|
|
|
|
|
SELECT * FROM t LIMIT 10;
|
|
|
|
|
|
2008-10-07 15:27:04 -04:00
|
|
|
-- UNION case should have same property
|
|
|
|
|
WITH RECURSIVE t(n) AS (
|
|
|
|
|
SELECT 1
|
|
|
|
|
UNION
|
|
|
|
|
SELECT n+1 FROM t)
|
|
|
|
|
SELECT * FROM t LIMIT 10;
|
|
|
|
|
|
2008-10-05 18:50:55 -04:00
|
|
|
-- Test behavior with an unknown-type literal in the WITH
|
|
|
|
|
WITH q AS (SELECT 'foo' AS x)
|
Remove undocumented IS [NOT] OF syntax.
This feature was added a long time ago, in 7c1e67bd5 and eb121ba2c,
but never documented in any user-facing way. (Documentation added
in 6126d3e70 was commented out almost immediately, in 8272fc3f7.)
That's because, while this syntax is defined by SQL:99, our
implementation is only vaguely related to the standard's semantics.
The standard appears to intend a run-time not parse-time test, and
it definitely intends that the test should understand subtype
relationships.
No one has stepped up to fix that in the intervening years, but
people keep coming across the code and asking why it's not documented.
Let's just get rid of it: if anyone ever wants to make it work per
spec, they can easily recover whatever parts of this code are still
of value from our git history.
If there's anyone out there who's actually using this despite its
undocumented status, they can switch to using pg_typeof() instead,
eg. "pg_typeof(something) = 'mytype'::regtype". That gives
essentially the same semantics as what our IS OF code did.
(We didn't have that function last time this was discussed, or
we would have ripped out IS OF then.)
Discussion: https://postgr.es/m/CAKFQuwZ2pTc-DSkOiTfjauqLYkNREeNZvWmeg12Q-_69D+sYZA@mail.gmail.com
Discussion: https://postgr.es/m/BAY20-F23E9F2B4DAB3E4E88D3623F99B0@phx.gbl
Discussion: https://postgr.es/m/3E7CF81D.1000203@joeconway.com
2020-11-19 17:39:39 -05:00
|
|
|
SELECT x, pg_typeof(x) FROM q;
|
2008-10-05 18:50:55 -04:00
|
|
|
|
|
|
|
|
WITH RECURSIVE t(n) AS (
|
|
|
|
|
SELECT 'foo'
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT n || ' bar' FROM t WHERE length(n) < 20
|
|
|
|
|
)
|
Remove undocumented IS [NOT] OF syntax.
This feature was added a long time ago, in 7c1e67bd5 and eb121ba2c,
but never documented in any user-facing way. (Documentation added
in 6126d3e70 was commented out almost immediately, in 8272fc3f7.)
That's because, while this syntax is defined by SQL:99, our
implementation is only vaguely related to the standard's semantics.
The standard appears to intend a run-time not parse-time test, and
it definitely intends that the test should understand subtype
relationships.
No one has stepped up to fix that in the intervening years, but
people keep coming across the code and asking why it's not documented.
Let's just get rid of it: if anyone ever wants to make it work per
spec, they can easily recover whatever parts of this code are still
of value from our git history.
If there's anyone out there who's actually using this despite its
undocumented status, they can switch to using pg_typeof() instead,
eg. "pg_typeof(something) = 'mytype'::regtype". That gives
essentially the same semantics as what our IS OF code did.
(We didn't have that function last time this was discussed, or
we would have ripped out IS OF then.)
Discussion: https://postgr.es/m/CAKFQuwZ2pTc-DSkOiTfjauqLYkNREeNZvWmeg12Q-_69D+sYZA@mail.gmail.com
Discussion: https://postgr.es/m/BAY20-F23E9F2B4DAB3E4E88D3623F99B0@phx.gbl
Discussion: https://postgr.es/m/3E7CF81D.1000203@joeconway.com
2020-11-19 17:39:39 -05:00
|
|
|
SELECT n, pg_typeof(n) FROM t;
|
Change unknown-type literals to type text in SELECT and RETURNING lists.
Previously, we left such literals alone if the query or subquery had
no properties forcing a type decision to be made (such as an ORDER BY or
DISTINCT clause using that output column). This meant that "unknown" could
be an exposed output column type, which has never been a great idea because
it could result in strange failures later on. For example, an outer query
that tried to do any operations on an unknown-type subquery output would
generally fail with some weird error like "failed to find conversion
function from unknown to text" or "could not determine which collation to
use for string comparison". Also, if the case occurred in a CREATE VIEW's
query then the view would have an unknown-type column, causing similar
failures in queries trying to use the view.
To fix, at the tail end of parse analysis of a query, forcibly convert any
remaining "unknown" literals in its SELECT or RETURNING list to type text.
However, provide a switch to suppress that, and use it in the cases of
SELECT inside a set operation or INSERT command. In those cases we already
had type resolution rules that make use of context information from outside
the subquery proper, and we don't want to change that behavior.
Also, change creation of an unknown-type column in a relation from a
warning to a hard error. The error should be unreachable now in CREATE
VIEW or CREATE MATVIEW, but it's still possible to explicitly say "unknown"
in CREATE TABLE or CREATE (composite) TYPE. We want to forbid that because
it's nothing but a foot-gun.
This change creates a pg_upgrade failure case: a matview that contains an
unknown-type column can't be pg_upgraded, because reparsing the matview's
defining query will now decide that the column is of type text, which
doesn't match the cstring-like storage that the old materialized column
would actually have. Add a checking pass to detect that. While at it,
we can detect tables or composite types that would fail, essentially
for free. Those would fail safely anyway later on, but we might as
well fail earlier.
This patch is by me, but it owes something to previous investigations
by Rahila Syed. Also thanks to Ashutosh Bapat and Michael Paquier for
review.
Discussion: https://postgr.es/m/CAH2L28uwwbL9HUM-WR=hromW1Cvamkn7O-g8fPY2m=_7muJ0oA@mail.gmail.com
2017-01-25 09:17:18 -05:00
|
|
|
|
|
|
|
|
-- In a perfect world, this would work and resolve the literal as int ...
|
|
|
|
|
-- but for now, we have to be content with resolving to text too soon.
|
|
|
|
|
WITH RECURSIVE t(n) AS (
|
|
|
|
|
SELECT '7'
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT n+1 FROM t WHERE n < 10
|
|
|
|
|
)
|
Remove undocumented IS [NOT] OF syntax.
This feature was added a long time ago, in 7c1e67bd5 and eb121ba2c,
but never documented in any user-facing way. (Documentation added
in 6126d3e70 was commented out almost immediately, in 8272fc3f7.)
That's because, while this syntax is defined by SQL:99, our
implementation is only vaguely related to the standard's semantics.
The standard appears to intend a run-time not parse-time test, and
it definitely intends that the test should understand subtype
relationships.
No one has stepped up to fix that in the intervening years, but
people keep coming across the code and asking why it's not documented.
Let's just get rid of it: if anyone ever wants to make it work per
spec, they can easily recover whatever parts of this code are still
of value from our git history.
If there's anyone out there who's actually using this despite its
undocumented status, they can switch to using pg_typeof() instead,
eg. "pg_typeof(something) = 'mytype'::regtype". That gives
essentially the same semantics as what our IS OF code did.
(We didn't have that function last time this was discussed, or
we would have ripped out IS OF then.)
Discussion: https://postgr.es/m/CAKFQuwZ2pTc-DSkOiTfjauqLYkNREeNZvWmeg12Q-_69D+sYZA@mail.gmail.com
Discussion: https://postgr.es/m/BAY20-F23E9F2B4DAB3E4E88D3623F99B0@phx.gbl
Discussion: https://postgr.es/m/3E7CF81D.1000203@joeconway.com
2020-11-19 17:39:39 -05:00
|
|
|
SELECT n, pg_typeof(n) FROM t;
|
2008-10-05 18:50:55 -04:00
|
|
|
|
2021-02-25 20:47:32 -05:00
|
|
|
-- Deeply nested WITH caused a list-munging problem in v13
|
|
|
|
|
-- Detection of cross-references and self-references
|
|
|
|
|
WITH RECURSIVE w1(c1) AS
|
|
|
|
|
(WITH w2(c2) AS
|
|
|
|
|
(WITH w3(c3) AS
|
|
|
|
|
(WITH w4(c4) AS
|
|
|
|
|
(WITH w5(c5) AS
|
|
|
|
|
(WITH RECURSIVE w6(c6) AS
|
|
|
|
|
(WITH w6(c6) AS
|
|
|
|
|
(WITH w8(c8) AS
|
|
|
|
|
(SELECT 1)
|
|
|
|
|
SELECT * FROM w8)
|
|
|
|
|
SELECT * FROM w6)
|
|
|
|
|
SELECT * FROM w6)
|
|
|
|
|
SELECT * FROM w5)
|
|
|
|
|
SELECT * FROM w4)
|
|
|
|
|
SELECT * FROM w3)
|
|
|
|
|
SELECT * FROM w2)
|
|
|
|
|
SELECT * FROM w1;
|
|
|
|
|
-- Detection of invalid self-references
|
|
|
|
|
WITH RECURSIVE outermost(x) AS (
|
|
|
|
|
SELECT 1
|
|
|
|
|
UNION (WITH innermost1 AS (
|
|
|
|
|
SELECT 2
|
|
|
|
|
UNION (WITH innermost2 AS (
|
|
|
|
|
SELECT 3
|
|
|
|
|
UNION (WITH innermost3 AS (
|
|
|
|
|
SELECT 4
|
|
|
|
|
UNION (WITH innermost4 AS (
|
|
|
|
|
SELECT 5
|
|
|
|
|
UNION (WITH innermost5 AS (
|
|
|
|
|
SELECT 6
|
|
|
|
|
UNION (WITH innermost6 AS
|
|
|
|
|
(SELECT 7)
|
|
|
|
|
SELECT * FROM innermost6))
|
|
|
|
|
SELECT * FROM innermost5))
|
|
|
|
|
SELECT * FROM innermost4))
|
|
|
|
|
SELECT * FROM innermost3))
|
|
|
|
|
SELECT * FROM innermost2))
|
|
|
|
|
SELECT * FROM outermost
|
|
|
|
|
UNION SELECT * FROM innermost1)
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM outermost ORDER BY 1;
|
|
|
|
|
|
2008-10-04 17:56:55 -04:00
|
|
|
--
|
|
|
|
|
-- Some examples with a tree
|
|
|
|
|
--
|
|
|
|
|
-- department structure represented here is as follows:
|
|
|
|
|
--
|
|
|
|
|
-- ROOT-+->A-+->B-+->C
|
|
|
|
|
-- | |
|
|
|
|
|
-- | +->D-+->F
|
|
|
|
|
-- +->E-+->G
|
|
|
|
|
|
|
|
|
|
CREATE TEMP TABLE department (
|
|
|
|
|
id INTEGER PRIMARY KEY, -- department ID
|
|
|
|
|
parent_department INTEGER REFERENCES department, -- upper department ID
|
|
|
|
|
name TEXT -- department name
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
INSERT INTO department VALUES (0, NULL, 'ROOT');
|
|
|
|
|
INSERT INTO department VALUES (1, 0, 'A');
|
|
|
|
|
INSERT INTO department VALUES (2, 1, 'B');
|
|
|
|
|
INSERT INTO department VALUES (3, 2, 'C');
|
|
|
|
|
INSERT INTO department VALUES (4, 2, 'D');
|
|
|
|
|
INSERT INTO department VALUES (5, 0, 'E');
|
|
|
|
|
INSERT INTO department VALUES (6, 4, 'F');
|
|
|
|
|
INSERT INTO department VALUES (7, 5, 'G');
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- extract all departments under 'A'. Result should be A, B, C, D and F
|
|
|
|
|
WITH RECURSIVE subdepartment AS
|
|
|
|
|
(
|
|
|
|
|
-- non recursive term
|
2008-10-05 18:20:17 -04:00
|
|
|
SELECT name as root_name, * FROM department WHERE name = 'A'
|
2008-10-04 17:56:55 -04:00
|
|
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
|
|
|
|
-- recursive term
|
2008-10-05 18:20:17 -04:00
|
|
|
SELECT sd.root_name, d.* FROM department AS d, subdepartment AS sd
|
2008-10-04 17:56:55 -04:00
|
|
|
WHERE d.parent_department = sd.id
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM subdepartment ORDER BY name;
|
|
|
|
|
|
|
|
|
|
-- extract all departments under 'A' with "level" number
|
|
|
|
|
WITH RECURSIVE subdepartment(level, id, parent_department, name) AS
|
|
|
|
|
(
|
|
|
|
|
-- non recursive term
|
|
|
|
|
SELECT 1, * FROM department WHERE name = 'A'
|
|
|
|
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
|
|
|
|
-- recursive term
|
|
|
|
|
SELECT sd.level + 1, d.* FROM department AS d, subdepartment AS sd
|
|
|
|
|
WHERE d.parent_department = sd.id
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM subdepartment ORDER BY name;
|
|
|
|
|
|
|
|
|
|
-- extract all departments under 'A' with "level" number.
|
|
|
|
|
-- Only shows level 2 or more
|
|
|
|
|
WITH RECURSIVE subdepartment(level, id, parent_department, name) AS
|
|
|
|
|
(
|
|
|
|
|
-- non recursive term
|
|
|
|
|
SELECT 1, * FROM department WHERE name = 'A'
|
|
|
|
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
|
|
|
|
-- recursive term
|
|
|
|
|
SELECT sd.level + 1, d.* FROM department AS d, subdepartment AS sd
|
|
|
|
|
WHERE d.parent_department = sd.id
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM subdepartment WHERE level >= 2 ORDER BY name;
|
|
|
|
|
|
|
|
|
|
-- "RECURSIVE" is ignored if the query has no self-reference
|
|
|
|
|
WITH RECURSIVE subdepartment AS
|
|
|
|
|
(
|
|
|
|
|
-- note lack of recursive UNION structure
|
|
|
|
|
SELECT * FROM department WHERE name = 'A'
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM subdepartment ORDER BY name;
|
|
|
|
|
|
|
|
|
|
-- inside subqueries
|
|
|
|
|
SELECT count(*) FROM (
|
|
|
|
|
WITH RECURSIVE t(n) AS (
|
|
|
|
|
SELECT 1 UNION ALL SELECT n + 1 FROM t WHERE n < 500
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM t) AS t WHERE n < (
|
|
|
|
|
SELECT count(*) FROM (
|
|
|
|
|
WITH RECURSIVE t(n) AS (
|
|
|
|
|
SELECT 1 UNION ALL SELECT n + 1 FROM t WHERE n < 100
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM t WHERE n < 50000
|
|
|
|
|
) AS t WHERE n < 100);
|
|
|
|
|
|
|
|
|
|
-- use same CTE twice at different subquery levels
|
|
|
|
|
WITH q1(x,y) AS (
|
|
|
|
|
SELECT hundred, sum(ten) FROM tenk1 GROUP BY hundred
|
|
|
|
|
)
|
|
|
|
|
SELECT count(*) FROM q1 WHERE y > (SELECT sum(y)/100 FROM q1 qsub);
|
|
|
|
|
|
|
|
|
|
-- via a VIEW
|
|
|
|
|
CREATE TEMPORARY VIEW vsubdepartment AS
|
|
|
|
|
WITH RECURSIVE subdepartment AS
|
|
|
|
|
(
|
|
|
|
|
-- non recursive term
|
|
|
|
|
SELECT * FROM department WHERE name = 'A'
|
|
|
|
|
UNION ALL
|
|
|
|
|
-- recursive term
|
|
|
|
|
SELECT d.* FROM department AS d, subdepartment AS sd
|
|
|
|
|
WHERE d.parent_department = sd.id
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM subdepartment;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM vsubdepartment ORDER BY name;
|
|
|
|
|
|
|
|
|
|
-- Check reverse listing
|
|
|
|
|
SELECT pg_get_viewdef('vsubdepartment'::regclass);
|
|
|
|
|
SELECT pg_get_viewdef('vsubdepartment'::regclass, true);
|
|
|
|
|
|
2012-10-12 16:14:11 -04:00
|
|
|
-- Another reverse-listing example
|
|
|
|
|
CREATE VIEW sums_1_100 AS
|
|
|
|
|
WITH RECURSIVE t(n) AS (
|
|
|
|
|
VALUES (1)
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT n+1 FROM t WHERE n < 100
|
|
|
|
|
)
|
|
|
|
|
SELECT sum(n) FROM t;
|
|
|
|
|
|
|
|
|
|
\d+ sums_1_100
|
|
|
|
|
|
2008-10-12 20:41:41 -04:00
|
|
|
-- corner case in which sub-WITH gets initialized first
|
|
|
|
|
with recursive q as (
|
|
|
|
|
select * from department
|
|
|
|
|
union all
|
|
|
|
|
(with x as (select * from q)
|
|
|
|
|
select * from x)
|
|
|
|
|
)
|
|
|
|
|
select * from q limit 24;
|
|
|
|
|
|
|
|
|
|
with recursive q as (
|
|
|
|
|
select * from department
|
|
|
|
|
union all
|
|
|
|
|
(with recursive x as (
|
|
|
|
|
select * from department
|
|
|
|
|
union all
|
|
|
|
|
(select * from q union all select * from x)
|
|
|
|
|
)
|
|
|
|
|
select * from x)
|
|
|
|
|
)
|
|
|
|
|
select * from q limit 32;
|
|
|
|
|
|
2008-10-04 17:56:55 -04:00
|
|
|
-- recursive term has sub-UNION
|
|
|
|
|
WITH RECURSIVE t(i,j) AS (
|
|
|
|
|
VALUES (1,2)
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT t2.i, t.j+1 FROM
|
|
|
|
|
(SELECT 2 AS i UNION ALL SELECT 3 AS i) AS t2
|
|
|
|
|
JOIN t ON (t2.i = t.i+1))
|
|
|
|
|
|
|
|
|
|
SELECT * FROM t;
|
|
|
|
|
|
|
|
|
|
--
|
|
|
|
|
-- different tree example
|
|
|
|
|
--
|
|
|
|
|
CREATE TEMPORARY TABLE tree(
|
|
|
|
|
id INTEGER PRIMARY KEY,
|
|
|
|
|
parent_id INTEGER REFERENCES tree(id)
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
INSERT INTO tree
|
|
|
|
|
VALUES (1, NULL), (2, 1), (3,1), (4,2), (5,2), (6,2), (7,3), (8,3),
|
|
|
|
|
(9,4), (10,4), (11,7), (12,7), (13,7), (14, 9), (15,11), (16,11);
|
|
|
|
|
|
|
|
|
|
--
|
|
|
|
|
-- get all paths from "second level" nodes to leaf nodes
|
|
|
|
|
--
|
|
|
|
|
WITH RECURSIVE t(id, path) AS (
|
|
|
|
|
VALUES(1,ARRAY[]::integer[])
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT tree.id, t.path || tree.id
|
|
|
|
|
FROM tree JOIN t ON (tree.parent_id = t.id)
|
|
|
|
|
)
|
|
|
|
|
SELECT t1.*, t2.* FROM t AS t1 JOIN t AS t2 ON
|
|
|
|
|
(t1.path[1] = t2.path[1] AND
|
|
|
|
|
array_upper(t1.path,1) = 1 AND
|
|
|
|
|
array_upper(t2.path,1) > 1)
|
|
|
|
|
ORDER BY t1.id, t2.id;
|
|
|
|
|
|
|
|
|
|
-- just count 'em
|
|
|
|
|
WITH RECURSIVE t(id, path) AS (
|
|
|
|
|
VALUES(1,ARRAY[]::integer[])
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT tree.id, t.path || tree.id
|
|
|
|
|
FROM tree JOIN t ON (tree.parent_id = t.id)
|
|
|
|
|
)
|
|
|
|
|
SELECT t1.id, count(t2.*) FROM t AS t1 JOIN t AS t2 ON
|
|
|
|
|
(t1.path[1] = t2.path[1] AND
|
|
|
|
|
array_upper(t1.path,1) = 1 AND
|
|
|
|
|
array_upper(t2.path,1) > 1)
|
|
|
|
|
GROUP BY t1.id
|
|
|
|
|
ORDER BY t1.id;
|
|
|
|
|
|
2009-03-30 00:08:43 -04:00
|
|
|
-- this variant tickled a whole-row-variable bug in 8.4devel
|
|
|
|
|
WITH RECURSIVE t(id, path) AS (
|
|
|
|
|
VALUES(1,ARRAY[]::integer[])
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT tree.id, t.path || tree.id
|
|
|
|
|
FROM tree JOIN t ON (tree.parent_id = t.id)
|
|
|
|
|
)
|
|
|
|
|
SELECT t1.id, t2.path, t2 FROM t AS t1 JOIN t AS t2 ON
|
|
|
|
|
(t1.id=t2.id);
|
|
|
|
|
|
2021-02-01 07:54:59 -05:00
|
|
|
-- SEARCH clause
|
|
|
|
|
|
|
|
|
|
create temp table graph0( f int, t int, label text );
|
|
|
|
|
|
|
|
|
|
insert into graph0 values
|
|
|
|
|
(1, 2, 'arc 1 -> 2'),
|
|
|
|
|
(1, 3, 'arc 1 -> 3'),
|
|
|
|
|
(2, 3, 'arc 2 -> 3'),
|
|
|
|
|
(1, 4, 'arc 1 -> 4'),
|
|
|
|
|
(4, 5, 'arc 4 -> 5');
|
|
|
|
|
|
2021-09-16 10:45:42 -04:00
|
|
|
explain (verbose, costs off)
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph0 g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph0 g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) search depth first by f, t set seq
|
|
|
|
|
select * from search_graph order by seq;
|
|
|
|
|
|
2021-02-01 07:54:59 -05:00
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph0 g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph0 g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) search depth first by f, t set seq
|
|
|
|
|
select * from search_graph order by seq;
|
|
|
|
|
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph0 g
|
|
|
|
|
union distinct
|
|
|
|
|
select g.*
|
|
|
|
|
from graph0 g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) search depth first by f, t set seq
|
|
|
|
|
select * from search_graph order by seq;
|
|
|
|
|
|
2021-09-16 10:45:42 -04:00
|
|
|
explain (verbose, costs off)
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph0 g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph0 g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) search breadth first by f, t set seq
|
|
|
|
|
select * from search_graph order by seq;
|
|
|
|
|
|
2021-02-01 07:54:59 -05:00
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph0 g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph0 g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) search breadth first by f, t set seq
|
|
|
|
|
select * from search_graph order by seq;
|
|
|
|
|
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph0 g
|
|
|
|
|
union distinct
|
|
|
|
|
select g.*
|
|
|
|
|
from graph0 g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) search breadth first by f, t set seq
|
|
|
|
|
select * from search_graph order by seq;
|
|
|
|
|
|
2022-10-16 19:18:08 -04:00
|
|
|
-- a constant initial value causes issues for EXPLAIN
|
|
|
|
|
explain (verbose, costs off)
|
|
|
|
|
with recursive test as (
|
|
|
|
|
select 1 as x
|
|
|
|
|
union all
|
|
|
|
|
select x + 1
|
|
|
|
|
from test
|
|
|
|
|
) search depth first by x set y
|
|
|
|
|
select * from test limit 5;
|
|
|
|
|
|
|
|
|
|
with recursive test as (
|
|
|
|
|
select 1 as x
|
|
|
|
|
union all
|
|
|
|
|
select x + 1
|
|
|
|
|
from test
|
|
|
|
|
) search depth first by x set y
|
|
|
|
|
select * from test limit 5;
|
|
|
|
|
|
|
|
|
|
explain (verbose, costs off)
|
|
|
|
|
with recursive test as (
|
|
|
|
|
select 1 as x
|
|
|
|
|
union all
|
|
|
|
|
select x + 1
|
|
|
|
|
from test
|
|
|
|
|
) search breadth first by x set y
|
|
|
|
|
select * from test limit 5;
|
|
|
|
|
|
|
|
|
|
with recursive test as (
|
|
|
|
|
select 1 as x
|
|
|
|
|
union all
|
|
|
|
|
select x + 1
|
|
|
|
|
from test
|
|
|
|
|
) search breadth first by x set y
|
|
|
|
|
select * from test limit 5;
|
|
|
|
|
|
2021-02-01 07:54:59 -05:00
|
|
|
-- various syntax errors
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph0 g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph0 g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) search depth first by foo, tar set seq
|
|
|
|
|
select * from search_graph;
|
|
|
|
|
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph0 g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph0 g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) search depth first by f, t set label
|
|
|
|
|
select * from search_graph;
|
|
|
|
|
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph0 g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph0 g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) search depth first by f, t, f set seq
|
|
|
|
|
select * from search_graph;
|
|
|
|
|
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph0 g
|
|
|
|
|
union all
|
|
|
|
|
select * from graph0 g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph0 g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) search depth first by f, t set seq
|
|
|
|
|
select * from search_graph order by seq;
|
|
|
|
|
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph0 g
|
|
|
|
|
union all
|
|
|
|
|
(select * from graph0 g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph0 g, search_graph sg
|
|
|
|
|
where g.f = sg.t)
|
|
|
|
|
) search depth first by f, t set seq
|
|
|
|
|
select * from search_graph order by seq;
|
|
|
|
|
|
2022-04-23 12:16:12 -04:00
|
|
|
-- check that we distinguish same CTE name used at different levels
|
|
|
|
|
-- (this case could be supported, perhaps, but it isn't today)
|
|
|
|
|
with recursive x(col) as (
|
|
|
|
|
select 1
|
|
|
|
|
union
|
|
|
|
|
(with x as (select * from x)
|
|
|
|
|
select * from x)
|
|
|
|
|
) search depth first by col set seq
|
|
|
|
|
select * from x;
|
|
|
|
|
|
2021-02-01 07:54:59 -05:00
|
|
|
-- test ruleutils and view expansion
|
|
|
|
|
create temp view v_search as
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph0 g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph0 g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) search depth first by f, t set seq
|
|
|
|
|
select f, t, label from search_graph;
|
|
|
|
|
|
|
|
|
|
select pg_get_viewdef('v_search');
|
|
|
|
|
|
|
|
|
|
select * from v_search;
|
|
|
|
|
|
2008-10-13 12:25:20 -04:00
|
|
|
--
|
|
|
|
|
-- test cycle detection
|
|
|
|
|
--
|
|
|
|
|
create temp table graph( f int, t int, label text );
|
|
|
|
|
|
|
|
|
|
insert into graph values
|
|
|
|
|
(1, 2, 'arc 1 -> 2'),
|
|
|
|
|
(1, 3, 'arc 1 -> 3'),
|
|
|
|
|
(2, 3, 'arc 2 -> 3'),
|
|
|
|
|
(1, 4, 'arc 1 -> 4'),
|
|
|
|
|
(4, 5, 'arc 4 -> 5'),
|
|
|
|
|
(5, 1, 'arc 5 -> 1');
|
|
|
|
|
|
2020-10-12 01:46:20 -04:00
|
|
|
with recursive search_graph(f, t, label, is_cycle, path) as (
|
|
|
|
|
select *, false, array[row(g.f, g.t)] from graph g
|
2008-10-13 12:25:20 -04:00
|
|
|
union all
|
2020-10-12 01:46:20 -04:00
|
|
|
select g.*, row(g.f, g.t) = any(path), path || row(g.f, g.t)
|
2008-10-13 12:25:20 -04:00
|
|
|
from graph g, search_graph sg
|
2020-10-12 01:46:20 -04:00
|
|
|
where g.f = sg.t and not is_cycle
|
2008-10-13 12:25:20 -04:00
|
|
|
)
|
|
|
|
|
select * from search_graph;
|
|
|
|
|
|
2020-11-19 03:24:37 -05:00
|
|
|
-- UNION DISTINCT exercises row type hashing support
|
2020-11-18 01:58:37 -05:00
|
|
|
with recursive search_graph(f, t, label, is_cycle, path) as (
|
|
|
|
|
select *, false, array[row(g.f, g.t)] from graph g
|
|
|
|
|
union distinct
|
|
|
|
|
select g.*, row(g.f, g.t) = any(path), path || row(g.f, g.t)
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t and not is_cycle
|
|
|
|
|
)
|
|
|
|
|
select * from search_graph;
|
|
|
|
|
|
2008-10-13 20:41:35 -04:00
|
|
|
-- ordering by the path column has same effect as SEARCH DEPTH FIRST
|
2020-10-12 01:46:20 -04:00
|
|
|
with recursive search_graph(f, t, label, is_cycle, path) as (
|
|
|
|
|
select *, false, array[row(g.f, g.t)] from graph g
|
2008-10-13 20:41:35 -04:00
|
|
|
union all
|
2020-10-12 01:46:20 -04:00
|
|
|
select g.*, row(g.f, g.t) = any(path), path || row(g.f, g.t)
|
2008-10-13 20:41:35 -04:00
|
|
|
from graph g, search_graph sg
|
2020-10-12 01:46:20 -04:00
|
|
|
where g.f = sg.t and not is_cycle
|
2008-10-13 20:41:35 -04:00
|
|
|
)
|
|
|
|
|
select * from search_graph order by path;
|
|
|
|
|
|
2021-02-01 07:54:59 -05:00
|
|
|
-- CYCLE clause
|
|
|
|
|
|
2021-09-16 10:45:42 -04:00
|
|
|
explain (verbose, costs off)
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) cycle f, t set is_cycle using path
|
|
|
|
|
select * from search_graph;
|
|
|
|
|
|
2021-02-01 07:54:59 -05:00
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
2021-02-27 02:11:14 -05:00
|
|
|
) cycle f, t set is_cycle using path
|
2021-02-01 07:54:59 -05:00
|
|
|
select * from search_graph;
|
|
|
|
|
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union distinct
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) cycle f, t set is_cycle to 'Y' default 'N' using path
|
|
|
|
|
select * from search_graph;
|
|
|
|
|
|
2022-10-16 19:18:08 -04:00
|
|
|
explain (verbose, costs off)
|
|
|
|
|
with recursive test as (
|
|
|
|
|
select 0 as x
|
|
|
|
|
union all
|
|
|
|
|
select (x + 1) % 10
|
|
|
|
|
from test
|
|
|
|
|
) cycle x set is_cycle using path
|
|
|
|
|
select * from test;
|
|
|
|
|
|
|
|
|
|
with recursive test as (
|
|
|
|
|
select 0 as x
|
|
|
|
|
union all
|
|
|
|
|
select (x + 1) % 10
|
|
|
|
|
from test
|
|
|
|
|
) cycle x set is_cycle using path
|
|
|
|
|
select * from test;
|
|
|
|
|
|
2022-12-16 13:07:42 -05:00
|
|
|
with recursive test as (
|
|
|
|
|
select 0 as x
|
|
|
|
|
union all
|
|
|
|
|
select (x + 1) % 10
|
|
|
|
|
from test
|
|
|
|
|
where not is_cycle -- redundant, but legal
|
|
|
|
|
) cycle x set is_cycle using path
|
|
|
|
|
select * from test;
|
|
|
|
|
|
2021-02-01 07:54:59 -05:00
|
|
|
-- multiple CTEs
|
|
|
|
|
with recursive
|
|
|
|
|
graph(f, t, label) as (
|
|
|
|
|
values (1, 2, 'arc 1 -> 2'),
|
|
|
|
|
(1, 3, 'arc 1 -> 3'),
|
|
|
|
|
(2, 3, 'arc 2 -> 3'),
|
|
|
|
|
(1, 4, 'arc 1 -> 4'),
|
|
|
|
|
(4, 5, 'arc 4 -> 5'),
|
|
|
|
|
(5, 1, 'arc 5 -> 1')
|
|
|
|
|
),
|
|
|
|
|
search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) cycle f, t set is_cycle to true default false using path
|
|
|
|
|
select f, t, label from search_graph;
|
|
|
|
|
|
|
|
|
|
-- star expansion
|
|
|
|
|
with recursive a as (
|
|
|
|
|
select 1 as b
|
|
|
|
|
union all
|
|
|
|
|
select * from a
|
2021-02-27 02:11:14 -05:00
|
|
|
) cycle b set c using p
|
2021-02-01 07:54:59 -05:00
|
|
|
select * from a;
|
|
|
|
|
|
|
|
|
|
-- search+cycle
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) search depth first by f, t set seq
|
2021-02-27 02:11:14 -05:00
|
|
|
cycle f, t set is_cycle using path
|
2021-02-01 07:54:59 -05:00
|
|
|
select * from search_graph;
|
|
|
|
|
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) search breadth first by f, t set seq
|
2021-02-27 02:11:14 -05:00
|
|
|
cycle f, t set is_cycle using path
|
2021-02-01 07:54:59 -05:00
|
|
|
select * from search_graph;
|
|
|
|
|
|
|
|
|
|
-- various syntax errors
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
2021-02-27 02:11:14 -05:00
|
|
|
) cycle foo, tar set is_cycle using path
|
2021-02-01 07:54:59 -05:00
|
|
|
select * from search_graph;
|
|
|
|
|
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) cycle f, t set is_cycle to true default 55 using path
|
|
|
|
|
select * from search_graph;
|
|
|
|
|
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) cycle f, t set is_cycle to point '(1,1)' default point '(0,0)' using path
|
|
|
|
|
select * from search_graph;
|
|
|
|
|
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) cycle f, t set label to true default false using path
|
|
|
|
|
select * from search_graph;
|
|
|
|
|
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) cycle f, t set is_cycle to true default false using label
|
|
|
|
|
select * from search_graph;
|
|
|
|
|
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) cycle f, t set foo to true default false using foo
|
|
|
|
|
select * from search_graph;
|
|
|
|
|
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) cycle f, t, f set is_cycle to true default false using path
|
|
|
|
|
select * from search_graph;
|
|
|
|
|
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) search depth first by f, t set foo
|
|
|
|
|
cycle f, t set foo to true default false using path
|
|
|
|
|
select * from search_graph;
|
|
|
|
|
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) search depth first by f, t set foo
|
|
|
|
|
cycle f, t set is_cycle to true default false using foo
|
|
|
|
|
select * from search_graph;
|
|
|
|
|
|
|
|
|
|
-- test ruleutils and view expansion
|
2021-02-27 02:11:14 -05:00
|
|
|
create temp view v_cycle1 as
|
2021-02-01 07:54:59 -05:00
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
2021-02-27 02:11:14 -05:00
|
|
|
) cycle f, t set is_cycle using path
|
|
|
|
|
select f, t, label from search_graph;
|
|
|
|
|
|
|
|
|
|
create temp view v_cycle2 as
|
|
|
|
|
with recursive search_graph(f, t, label) as (
|
|
|
|
|
select * from graph g
|
|
|
|
|
union all
|
|
|
|
|
select g.*
|
|
|
|
|
from graph g, search_graph sg
|
|
|
|
|
where g.f = sg.t
|
|
|
|
|
) cycle f, t set is_cycle to 'Y' default 'N' using path
|
2021-02-01 07:54:59 -05:00
|
|
|
select f, t, label from search_graph;
|
|
|
|
|
|
2021-02-27 02:11:14 -05:00
|
|
|
select pg_get_viewdef('v_cycle1');
|
|
|
|
|
select pg_get_viewdef('v_cycle2');
|
2021-02-01 07:54:59 -05:00
|
|
|
|
2021-02-27 02:11:14 -05:00
|
|
|
select * from v_cycle1;
|
|
|
|
|
select * from v_cycle2;
|
2021-02-01 07:54:59 -05:00
|
|
|
|
2008-10-04 17:56:55 -04:00
|
|
|
--
|
|
|
|
|
-- test multiple WITH queries
|
|
|
|
|
--
|
|
|
|
|
WITH RECURSIVE
|
|
|
|
|
y (id) AS (VALUES (1)),
|
|
|
|
|
x (id) AS (SELECT * FROM y UNION ALL SELECT id+1 FROM x WHERE id < 5)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
-- forward reference OK
|
|
|
|
|
WITH RECURSIVE
|
|
|
|
|
x(id) AS (SELECT * FROM y UNION ALL SELECT id+1 FROM x WHERE id < 5),
|
|
|
|
|
y(id) AS (values (1))
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE
|
|
|
|
|
x(id) AS
|
|
|
|
|
(VALUES (1) UNION ALL SELECT id+1 FROM x WHERE id < 5),
|
|
|
|
|
y(id) AS
|
|
|
|
|
(VALUES (1) UNION ALL SELECT id+1 FROM y WHERE id < 10)
|
|
|
|
|
SELECT y.*, x.* FROM y LEFT JOIN x USING (id);
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE
|
|
|
|
|
x(id) AS
|
|
|
|
|
(VALUES (1) UNION ALL SELECT id+1 FROM x WHERE id < 5),
|
|
|
|
|
y(id) AS
|
|
|
|
|
(VALUES (1) UNION ALL SELECT id+1 FROM x WHERE id < 10)
|
|
|
|
|
SELECT y.*, x.* FROM y LEFT JOIN x USING (id);
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE
|
|
|
|
|
x(id) AS
|
|
|
|
|
(SELECT 1 UNION ALL SELECT id+1 FROM x WHERE id < 3 ),
|
|
|
|
|
y(id) AS
|
|
|
|
|
(SELECT * FROM x UNION ALL SELECT * FROM x),
|
|
|
|
|
z(id) AS
|
|
|
|
|
(SELECT * FROM x UNION ALL SELECT id+1 FROM z WHERE id < 10)
|
|
|
|
|
SELECT * FROM z;
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE
|
|
|
|
|
x(id) AS
|
|
|
|
|
(SELECT 1 UNION ALL SELECT id+1 FROM x WHERE id < 3 ),
|
|
|
|
|
y(id) AS
|
|
|
|
|
(SELECT * FROM x UNION ALL SELECT * FROM x),
|
|
|
|
|
z(id) AS
|
|
|
|
|
(SELECT * FROM y UNION ALL SELECT id+1 FROM z WHERE id < 10)
|
|
|
|
|
SELECT * FROM z;
|
|
|
|
|
|
2010-10-15 19:53:59 -04:00
|
|
|
--
|
2011-02-25 18:56:23 -05:00
|
|
|
-- Test WITH attached to a data-modifying statement
|
2010-10-15 19:53:59 -04:00
|
|
|
--
|
|
|
|
|
|
|
|
|
|
CREATE TEMPORARY TABLE y (a INTEGER);
|
|
|
|
|
INSERT INTO y SELECT generate_series(1, 10);
|
|
|
|
|
|
|
|
|
|
WITH t AS (
|
|
|
|
|
SELECT a FROM y
|
|
|
|
|
)
|
|
|
|
|
INSERT INTO y
|
|
|
|
|
SELECT a+20 FROM t RETURNING *;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM y;
|
|
|
|
|
|
|
|
|
|
WITH t AS (
|
|
|
|
|
SELECT a FROM y
|
|
|
|
|
)
|
|
|
|
|
UPDATE y SET a = y.a-10 FROM t WHERE y.a > 20 AND t.a = y.a RETURNING y.a;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM y;
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE t(a) AS (
|
|
|
|
|
SELECT 11
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT a+1 FROM t WHERE a < 50
|
|
|
|
|
)
|
|
|
|
|
DELETE FROM y USING t WHERE t.a = y.a RETURNING y.a;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM y;
|
|
|
|
|
|
|
|
|
|
DROP TABLE y;
|
|
|
|
|
|
2008-10-04 17:56:55 -04:00
|
|
|
--
|
|
|
|
|
-- error cases
|
|
|
|
|
--
|
|
|
|
|
|
2022-05-18 14:28:31 -04:00
|
|
|
WITH x(n, b) AS (SELECT 1)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
2008-10-04 17:56:55 -04:00
|
|
|
-- INTERSECT
|
|
|
|
|
WITH RECURSIVE x(n) AS (SELECT 1 INTERSECT SELECT n+1 FROM x)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE x(n) AS (SELECT 1 INTERSECT ALL SELECT n+1 FROM x)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
-- EXCEPT
|
|
|
|
|
WITH RECURSIVE x(n) AS (SELECT 1 EXCEPT SELECT n+1 FROM x)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE x(n) AS (SELECT 1 EXCEPT ALL SELECT n+1 FROM x)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
-- no non-recursive term
|
|
|
|
|
WITH RECURSIVE x(n) AS (SELECT n FROM x)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
-- recursive term in the left hand side (strictly speaking, should allow this)
|
|
|
|
|
WITH RECURSIVE x(n) AS (SELECT n FROM x UNION ALL SELECT 1)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
CREATE TEMPORARY TABLE y (a INTEGER);
|
|
|
|
|
INSERT INTO y SELECT generate_series(1, 10);
|
|
|
|
|
|
|
|
|
|
-- LEFT JOIN
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE x(n) AS (SELECT a FROM y WHERE a = 1
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT x.n+1 FROM y LEFT JOIN x ON x.n = y.a WHERE n < 10)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
-- RIGHT JOIN
|
|
|
|
|
WITH RECURSIVE x(n) AS (SELECT a FROM y WHERE a = 1
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT x.n+1 FROM x RIGHT JOIN y ON x.n = y.a WHERE n < 10)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
-- FULL JOIN
|
|
|
|
|
WITH RECURSIVE x(n) AS (SELECT a FROM y WHERE a = 1
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT x.n+1 FROM x FULL JOIN y ON x.n = y.a WHERE n < 10)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
-- subquery
|
|
|
|
|
WITH RECURSIVE x(n) AS (SELECT 1 UNION ALL SELECT n+1 FROM x
|
|
|
|
|
WHERE n IN (SELECT * FROM x))
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
-- aggregate functions
|
|
|
|
|
WITH RECURSIVE x(n) AS (SELECT 1 UNION ALL SELECT count(*) FROM x)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE x(n) AS (SELECT 1 UNION ALL SELECT sum(n) FROM x)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
-- ORDER BY
|
|
|
|
|
WITH RECURSIVE x(n) AS (SELECT 1 UNION ALL SELECT n+1 FROM x ORDER BY 1)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
-- LIMIT/OFFSET
|
|
|
|
|
WITH RECURSIVE x(n) AS (SELECT 1 UNION ALL SELECT n+1 FROM x LIMIT 10 OFFSET 1)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
-- FOR UPDATE
|
|
|
|
|
WITH RECURSIVE x(n) AS (SELECT 1 UNION ALL SELECT n+1 FROM x FOR UPDATE)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
-- target list has a recursive query name
|
|
|
|
|
WITH RECURSIVE x(id) AS (values (1)
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT (SELECT * FROM x) FROM x WHERE id < 5
|
|
|
|
|
) SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
-- mutual recursive query (not implemented)
|
|
|
|
|
WITH RECURSIVE
|
|
|
|
|
x (id) AS (SELECT 1 UNION ALL SELECT id+1 FROM y WHERE id < 5),
|
|
|
|
|
y (id) AS (SELECT 1 UNION ALL SELECT id+1 FROM x WHERE id < 5)
|
|
|
|
|
SELECT * FROM x;
|
|
|
|
|
|
|
|
|
|
-- non-linear recursion is not allowed
|
|
|
|
|
WITH RECURSIVE foo(i) AS
|
|
|
|
|
(values (1)
|
|
|
|
|
UNION ALL
|
|
|
|
|
(SELECT i+1 FROM foo WHERE i < 10
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT i+1 FROM foo WHERE i < 5)
|
|
|
|
|
) SELECT * FROM foo;
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE foo(i) AS
|
|
|
|
|
(values (1)
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT * FROM
|
|
|
|
|
(SELECT i+1 FROM foo WHERE i < 10
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT i+1 FROM foo WHERE i < 5) AS t
|
|
|
|
|
) SELECT * FROM foo;
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE foo(i) AS
|
|
|
|
|
(values (1)
|
|
|
|
|
UNION ALL
|
|
|
|
|
(SELECT i+1 FROM foo WHERE i < 10
|
|
|
|
|
EXCEPT
|
|
|
|
|
SELECT i+1 FROM foo WHERE i < 5)
|
|
|
|
|
) SELECT * FROM foo;
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE foo(i) AS
|
|
|
|
|
(values (1)
|
|
|
|
|
UNION ALL
|
|
|
|
|
(SELECT i+1 FROM foo WHERE i < 10
|
|
|
|
|
INTERSECT
|
|
|
|
|
SELECT i+1 FROM foo WHERE i < 5)
|
|
|
|
|
) SELECT * FROM foo;
|
|
|
|
|
|
|
|
|
|
-- Wrong type induced from non-recursive term
|
|
|
|
|
WITH RECURSIVE foo(i) AS
|
|
|
|
|
(SELECT i FROM (VALUES(1),(2)) t(i)
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT (i+1)::numeric(10,0) FROM foo WHERE i < 10)
|
|
|
|
|
SELECT * FROM foo;
|
|
|
|
|
|
|
|
|
|
-- rejects different typmod, too (should we allow this?)
|
|
|
|
|
WITH RECURSIVE foo(i) AS
|
|
|
|
|
(SELECT i::numeric(3,0) FROM (VALUES(1),(2)) t(i)
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT (i+1)::numeric(10,0) FROM foo WHERE i < 10)
|
|
|
|
|
SELECT * FROM foo;
|
2009-07-05 22:16:03 -04:00
|
|
|
|
2010-10-15 19:53:59 -04:00
|
|
|
-- disallow OLD/NEW reference in CTE
|
|
|
|
|
CREATE TEMPORARY TABLE x (n integer);
|
|
|
|
|
CREATE RULE r2 AS ON UPDATE TO x DO INSTEAD
|
|
|
|
|
WITH t AS (SELECT OLD.*) UPDATE y SET a = t.n FROM t;
|
|
|
|
|
|
2009-07-05 22:16:03 -04:00
|
|
|
--
|
|
|
|
|
-- test for bug #4902
|
|
|
|
|
--
|
|
|
|
|
with cte(foo) as ( values(42) ) values((select foo from cte));
|
|
|
|
|
with cte(foo) as ( select 42 ) select * from ((select foo from cte)) q;
|
|
|
|
|
|
|
|
|
|
-- test CTE referencing an outer-level variable (to see that changed-parameter
|
|
|
|
|
-- signaling still works properly after fixing this bug)
|
|
|
|
|
select ( with cte(foo) as ( values(f1) )
|
|
|
|
|
select (select foo from cte) )
|
|
|
|
|
from int4_tbl;
|
|
|
|
|
|
|
|
|
|
select ( with cte(foo) as ( values(f1) )
|
|
|
|
|
values((select foo from cte)) )
|
|
|
|
|
from int4_tbl;
|
2009-09-08 23:32:52 -04:00
|
|
|
|
|
|
|
|
--
|
|
|
|
|
-- test for nested-recursive-WITH bug
|
|
|
|
|
--
|
|
|
|
|
WITH RECURSIVE t(j) AS (
|
|
|
|
|
WITH RECURSIVE s(i) AS (
|
|
|
|
|
VALUES (1)
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT i+1 FROM s WHERE i < 10
|
|
|
|
|
)
|
|
|
|
|
SELECT i FROM s
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT j+1 FROM t WHERE j < 10
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM t;
|
2011-02-25 18:56:23 -05:00
|
|
|
|
2012-07-31 17:56:21 -04:00
|
|
|
--
|
|
|
|
|
-- test WITH attached to intermediate-level set operation
|
|
|
|
|
--
|
|
|
|
|
|
|
|
|
|
WITH outermost(x) AS (
|
|
|
|
|
SELECT 1
|
|
|
|
|
UNION (WITH innermost as (SELECT 2)
|
|
|
|
|
SELECT * FROM innermost
|
|
|
|
|
UNION SELECT 3)
|
|
|
|
|
)
|
2016-10-10 16:41:57 -04:00
|
|
|
SELECT * FROM outermost ORDER BY 1;
|
2012-07-31 17:56:21 -04:00
|
|
|
|
|
|
|
|
WITH outermost(x) AS (
|
|
|
|
|
SELECT 1
|
|
|
|
|
UNION (WITH innermost as (SELECT 2)
|
|
|
|
|
SELECT * FROM outermost -- fail
|
|
|
|
|
UNION SELECT * FROM innermost)
|
|
|
|
|
)
|
2016-10-10 16:41:57 -04:00
|
|
|
SELECT * FROM outermost ORDER BY 1;
|
2012-07-31 17:56:21 -04:00
|
|
|
|
|
|
|
|
WITH RECURSIVE outermost(x) AS (
|
|
|
|
|
SELECT 1
|
|
|
|
|
UNION (WITH innermost as (SELECT 2)
|
|
|
|
|
SELECT * FROM outermost
|
|
|
|
|
UNION SELECT * FROM innermost)
|
|
|
|
|
)
|
2016-10-10 16:41:57 -04:00
|
|
|
SELECT * FROM outermost ORDER BY 1;
|
2012-07-31 17:56:21 -04:00
|
|
|
|
|
|
|
|
WITH RECURSIVE outermost(x) AS (
|
|
|
|
|
WITH innermost as (SELECT 2 FROM outermost) -- fail
|
|
|
|
|
SELECT * FROM innermost
|
|
|
|
|
UNION SELECT * from outermost
|
|
|
|
|
)
|
2016-10-10 16:41:57 -04:00
|
|
|
SELECT * FROM outermost ORDER BY 1;
|
2012-07-31 17:56:21 -04:00
|
|
|
|
Fix PARAM_EXEC assignment mechanism to be safe in the presence of WITH.
The planner previously assumed that parameter Vars having the same absolute
query level, varno, and varattno could safely be assigned the same runtime
PARAM_EXEC slot, even though they might be different Vars appearing in
different subqueries. This was (probably) safe before the introduction of
CTEs, but the lazy-evalution mechanism used for CTEs means that a CTE can
be executed during execution of some other subquery, causing the lifespan
of Params at the same syntactic nesting level as the CTE to overlap with
use of the same slots inside the CTE. In 9.1 we created additional hazards
by using the same parameter-assignment technology for nestloop inner scan
parameters, but it was broken before that, as illustrated by the added
regression test.
To fix, restructure the planner's management of PlannerParamItems so that
items having different semantic lifespans are kept rigorously separated.
This will probably result in complex queries using more runtime PARAM_EXEC
slots than before, but the slots are cheap enough that this hardly matters.
Also, stop generating PlannerParamItems containing Params for subquery
outputs: all we really need to do is reserve the PARAM_EXEC slot number,
and that now only takes incrementing a counter. The planning code is
simpler and probably faster than before, as well as being more correct.
Per report from Vik Reykja.
These changes will mostly also need to be made in the back branches, but
I'm going to hold off on that until after 9.2.0 wraps.
2012-09-05 12:54:03 -04:00
|
|
|
--
|
|
|
|
|
-- This test will fail with the old implementation of PARAM_EXEC parameter
|
|
|
|
|
-- assignment, because the "q1" Var passed down to A's targetlist subselect
|
|
|
|
|
-- looks exactly like the "A.id" Var passed down to C's subselect, causing
|
|
|
|
|
-- the old code to give them the same runtime PARAM_EXEC slot. But the
|
|
|
|
|
-- lifespans of the two parameters overlap, thanks to B also reading A.
|
|
|
|
|
--
|
|
|
|
|
|
|
|
|
|
with
|
|
|
|
|
A as ( select q2 as id, (select q1) as x from int8_tbl ),
|
|
|
|
|
B as ( select id, row_number() over (partition by id) as r from A ),
|
|
|
|
|
C as ( select A.id, array(select B.id from B where B.id = A.id) from A )
|
|
|
|
|
select * from C;
|
|
|
|
|
|
2012-08-15 19:01:16 -04:00
|
|
|
--
|
|
|
|
|
-- Test CTEs read in non-initialization orders
|
|
|
|
|
--
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE
|
|
|
|
|
tab(id_key,link) AS (VALUES (1,17), (2,17), (3,17), (4,17), (6,17), (5,17)),
|
|
|
|
|
iter (id_key, row_type, link) AS (
|
|
|
|
|
SELECT 0, 'base', 17
|
|
|
|
|
UNION ALL (
|
|
|
|
|
WITH remaining(id_key, row_type, link, min) AS (
|
|
|
|
|
SELECT tab.id_key, 'true'::text, iter.link, MIN(tab.id_key) OVER ()
|
|
|
|
|
FROM tab INNER JOIN iter USING (link)
|
|
|
|
|
WHERE tab.id_key > iter.id_key
|
|
|
|
|
),
|
|
|
|
|
first_remaining AS (
|
|
|
|
|
SELECT id_key, row_type, link
|
|
|
|
|
FROM remaining
|
|
|
|
|
WHERE id_key=min
|
|
|
|
|
),
|
|
|
|
|
effect AS (
|
|
|
|
|
SELECT tab.id_key, 'new'::text, tab.link
|
|
|
|
|
FROM first_remaining e INNER JOIN tab ON e.id_key=tab.id_key
|
|
|
|
|
WHERE e.row_type = 'false'
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM first_remaining
|
|
|
|
|
UNION ALL SELECT * FROM effect
|
|
|
|
|
)
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM iter;
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE
|
|
|
|
|
tab(id_key,link) AS (VALUES (1,17), (2,17), (3,17), (4,17), (6,17), (5,17)),
|
|
|
|
|
iter (id_key, row_type, link) AS (
|
|
|
|
|
SELECT 0, 'base', 17
|
|
|
|
|
UNION (
|
|
|
|
|
WITH remaining(id_key, row_type, link, min) AS (
|
|
|
|
|
SELECT tab.id_key, 'true'::text, iter.link, MIN(tab.id_key) OVER ()
|
|
|
|
|
FROM tab INNER JOIN iter USING (link)
|
|
|
|
|
WHERE tab.id_key > iter.id_key
|
|
|
|
|
),
|
|
|
|
|
first_remaining AS (
|
|
|
|
|
SELECT id_key, row_type, link
|
|
|
|
|
FROM remaining
|
|
|
|
|
WHERE id_key=min
|
|
|
|
|
),
|
|
|
|
|
effect AS (
|
|
|
|
|
SELECT tab.id_key, 'new'::text, tab.link
|
|
|
|
|
FROM first_remaining e INNER JOIN tab ON e.id_key=tab.id_key
|
|
|
|
|
WHERE e.row_type = 'false'
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM first_remaining
|
|
|
|
|
UNION ALL SELECT * FROM effect
|
|
|
|
|
)
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM iter;
|
|
|
|
|
|
2011-02-25 18:56:23 -05:00
|
|
|
--
|
|
|
|
|
-- Data-modifying statements in WITH
|
|
|
|
|
--
|
|
|
|
|
|
|
|
|
|
-- INSERT ... RETURNING
|
|
|
|
|
WITH t AS (
|
|
|
|
|
INSERT INTO y
|
|
|
|
|
VALUES
|
|
|
|
|
(11),
|
|
|
|
|
(12),
|
|
|
|
|
(13),
|
|
|
|
|
(14),
|
|
|
|
|
(15),
|
|
|
|
|
(16),
|
|
|
|
|
(17),
|
|
|
|
|
(18),
|
|
|
|
|
(19),
|
|
|
|
|
(20)
|
|
|
|
|
RETURNING *
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM t;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM y;
|
|
|
|
|
|
|
|
|
|
-- UPDATE ... RETURNING
|
|
|
|
|
WITH t AS (
|
|
|
|
|
UPDATE y
|
|
|
|
|
SET a=a+1
|
|
|
|
|
RETURNING *
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM t;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM y;
|
|
|
|
|
|
|
|
|
|
-- DELETE ... RETURNING
|
|
|
|
|
WITH t AS (
|
|
|
|
|
DELETE FROM y
|
|
|
|
|
WHERE a <= 10
|
|
|
|
|
RETURNING *
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM t;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM y;
|
|
|
|
|
|
|
|
|
|
-- forward reference
|
|
|
|
|
WITH RECURSIVE t AS (
|
|
|
|
|
INSERT INTO y
|
|
|
|
|
SELECT a+5 FROM t2 WHERE a > 5
|
|
|
|
|
RETURNING *
|
|
|
|
|
), t2 AS (
|
|
|
|
|
UPDATE y SET a=a-11 RETURNING *
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM t
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT * FROM t2;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM y;
|
|
|
|
|
|
|
|
|
|
-- unconditional DO INSTEAD rule
|
|
|
|
|
CREATE RULE y_rule AS ON DELETE TO y DO INSTEAD
|
|
|
|
|
INSERT INTO y VALUES(42) RETURNING *;
|
|
|
|
|
|
|
|
|
|
WITH t AS (
|
|
|
|
|
DELETE FROM y RETURNING *
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM t;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM y;
|
|
|
|
|
|
|
|
|
|
DROP RULE y_rule ON y;
|
|
|
|
|
|
2011-06-07 00:08:31 -04:00
|
|
|
-- check merging of outer CTE with CTE in a rule action
|
|
|
|
|
CREATE TEMP TABLE bug6051 AS
|
|
|
|
|
select i from generate_series(1,3) as t(i);
|
|
|
|
|
|
|
|
|
|
SELECT * FROM bug6051;
|
|
|
|
|
|
|
|
|
|
WITH t1 AS ( DELETE FROM bug6051 RETURNING * )
|
|
|
|
|
INSERT INTO bug6051 SELECT * FROM t1;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM bug6051;
|
|
|
|
|
|
|
|
|
|
CREATE TEMP TABLE bug6051_2 (i int);
|
|
|
|
|
|
|
|
|
|
CREATE RULE bug6051_ins AS ON INSERT TO bug6051 DO INSTEAD
|
|
|
|
|
INSERT INTO bug6051_2
|
2021-09-08 12:05:43 -04:00
|
|
|
VALUES(NEW.i);
|
2011-06-07 00:08:31 -04:00
|
|
|
|
|
|
|
|
WITH t1 AS ( DELETE FROM bug6051 RETURNING * )
|
|
|
|
|
INSERT INTO bug6051 SELECT * FROM t1;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM bug6051;
|
|
|
|
|
SELECT * FROM bug6051_2;
|
|
|
|
|
|
2022-09-15 00:40:17 -04:00
|
|
|
-- check INSERT ... SELECT rule actions are disallowed on commands
|
2021-09-08 12:05:43 -04:00
|
|
|
-- that have modifyingCTEs
|
|
|
|
|
CREATE OR REPLACE RULE bug6051_ins AS ON INSERT TO bug6051 DO INSTEAD
|
|
|
|
|
INSERT INTO bug6051_2
|
|
|
|
|
SELECT NEW.i;
|
|
|
|
|
|
|
|
|
|
WITH t1 AS ( DELETE FROM bug6051 RETURNING * )
|
|
|
|
|
INSERT INTO bug6051 SELECT * FROM t1;
|
|
|
|
|
|
|
|
|
|
-- silly example to verify that hasModifyingCTE flag is propagated
|
|
|
|
|
CREATE TEMP TABLE bug6051_3 AS
|
|
|
|
|
SELECT a FROM generate_series(11,13) AS a;
|
|
|
|
|
|
|
|
|
|
CREATE RULE bug6051_3_ins AS ON INSERT TO bug6051_3 DO INSTEAD
|
|
|
|
|
SELECT i FROM bug6051_2;
|
|
|
|
|
|
2023-02-15 03:21:59 -05:00
|
|
|
BEGIN; SET LOCAL debug_parallel_query = on;
|
2021-09-08 12:05:43 -04:00
|
|
|
|
|
|
|
|
WITH t1 AS ( DELETE FROM bug6051_3 RETURNING * )
|
|
|
|
|
INSERT INTO bug6051_3 SELECT * FROM t1;
|
|
|
|
|
|
|
|
|
|
COMMIT;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM bug6051_3;
|
|
|
|
|
|
2022-04-21 17:58:52 -04:00
|
|
|
-- check case where CTE reference is removed due to optimization
|
|
|
|
|
EXPLAIN (VERBOSE, COSTS OFF)
|
|
|
|
|
SELECT q1 FROM
|
|
|
|
|
(
|
|
|
|
|
WITH t_cte AS (SELECT * FROM int8_tbl t)
|
|
|
|
|
SELECT q1, (SELECT q2 FROM t_cte WHERE t_cte.q1 = i8.q1) AS t_sub
|
|
|
|
|
FROM int8_tbl i8
|
|
|
|
|
) ss;
|
|
|
|
|
|
|
|
|
|
SELECT q1 FROM
|
|
|
|
|
(
|
|
|
|
|
WITH t_cte AS (SELECT * FROM int8_tbl t)
|
|
|
|
|
SELECT q1, (SELECT q2 FROM t_cte WHERE t_cte.q1 = i8.q1) AS t_sub
|
|
|
|
|
FROM int8_tbl i8
|
|
|
|
|
) ss;
|
|
|
|
|
|
|
|
|
|
EXPLAIN (VERBOSE, COSTS OFF)
|
|
|
|
|
SELECT q1 FROM
|
|
|
|
|
(
|
|
|
|
|
WITH t_cte AS MATERIALIZED (SELECT * FROM int8_tbl t)
|
|
|
|
|
SELECT q1, (SELECT q2 FROM t_cte WHERE t_cte.q1 = i8.q1) AS t_sub
|
|
|
|
|
FROM int8_tbl i8
|
|
|
|
|
) ss;
|
|
|
|
|
|
|
|
|
|
SELECT q1 FROM
|
|
|
|
|
(
|
|
|
|
|
WITH t_cte AS MATERIALIZED (SELECT * FROM int8_tbl t)
|
|
|
|
|
SELECT q1, (SELECT q2 FROM t_cte WHERE t_cte.q1 = i8.q1) AS t_sub
|
|
|
|
|
FROM int8_tbl i8
|
|
|
|
|
) ss;
|
|
|
|
|
|
2011-02-25 18:56:23 -05:00
|
|
|
-- a truly recursive CTE in the same list
|
|
|
|
|
WITH RECURSIVE t(a) AS (
|
|
|
|
|
SELECT 0
|
|
|
|
|
UNION ALL
|
|
|
|
|
SELECT a+1 FROM t WHERE a+1 < 5
|
|
|
|
|
), t2 as (
|
|
|
|
|
INSERT INTO y
|
|
|
|
|
SELECT * FROM t RETURNING *
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM t2 JOIN y USING (a) ORDER BY a;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM y;
|
|
|
|
|
|
|
|
|
|
-- data-modifying WITH in a modifying statement
|
|
|
|
|
WITH t AS (
|
|
|
|
|
DELETE FROM y
|
|
|
|
|
WHERE a <= 10
|
|
|
|
|
RETURNING *
|
|
|
|
|
)
|
|
|
|
|
INSERT INTO y SELECT -a FROM t RETURNING *;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM y;
|
|
|
|
|
|
|
|
|
|
-- check that WITH query is run to completion even if outer query isn't
|
|
|
|
|
WITH t AS (
|
|
|
|
|
UPDATE y SET a = a * 100 RETURNING *
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM t LIMIT 10;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM y;
|
|
|
|
|
|
Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint. DO NOTHING avoids the
constraint violation, without touching the pre-existing row. DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed. The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.
This feature is often referred to as upsert.
This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert. If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made. If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.
To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.
Bumps catversion as stored rules change.
Author: Peter Geoghegan, with significant contributions from Heikki
Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
Dean Rasheed, Stephen Frost and many others.
2015-05-07 23:31:36 -04:00
|
|
|
-- data-modifying WITH containing INSERT...ON CONFLICT DO UPDATE
|
Clean up duplicate table and function names in regression tests.
Many of the objects we create during the regression tests are put in the
public schema, so that using the same names in different regression tests
creates a hazard of test failures if any two such scripts run concurrently.
This patch cleans up a bunch of latent hazards of that sort, as well as two
live hazards.
The current situation in this regard is far worse than it was a year or two
back, because practically all of the partitioning-related test cases have
reused table names with enthusiasm. I despaired of cleaning up that mess
within the five most-affected tests (create_table, alter_table, insert,
update, inherit); fortunately those don't run concurrently.
Other than partitioning problems, most of the issues boil down to using
names like "foo", "bar", "tmp", etc, without thought for the fact that
other test scripts might use similar names concurrently. I've made an
effort to make all such names more specific.
One of the live hazards was that commit 7421f4b8 caused with.sql to
create a table named "test", conflicting with a similarly-named table
in alter_table.sql; this was exposed in the buildfarm recently.
The other one was that join.sql and transactions.sql both create tables
named "foo" and "bar"; but join.sql's uses of those names date back
only to December or so.
Since commit 7421f4b8 was back-patched to v10, back-patch a minimal
fix for that problem. The rest of this is just future-proofing.
Discussion: https://postgr.es/m/4627.1521070268@sss.pgh.pa.us
2018-03-15 17:08:51 -04:00
|
|
|
CREATE TABLE withz AS SELECT i AS k, (i || ' v')::text v FROM generate_series(1, 16, 3) i;
|
|
|
|
|
ALTER TABLE withz ADD UNIQUE (k);
|
Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint. DO NOTHING avoids the
constraint violation, without touching the pre-existing row. DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed. The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.
This feature is often referred to as upsert.
This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert. If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made. If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.
To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.
Bumps catversion as stored rules change.
Author: Peter Geoghegan, with significant contributions from Heikki
Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
Dean Rasheed, Stephen Frost and many others.
2015-05-07 23:31:36 -04:00
|
|
|
|
|
|
|
|
WITH t AS (
|
Clean up duplicate table and function names in regression tests.
Many of the objects we create during the regression tests are put in the
public schema, so that using the same names in different regression tests
creates a hazard of test failures if any two such scripts run concurrently.
This patch cleans up a bunch of latent hazards of that sort, as well as two
live hazards.
The current situation in this regard is far worse than it was a year or two
back, because practically all of the partitioning-related test cases have
reused table names with enthusiasm. I despaired of cleaning up that mess
within the five most-affected tests (create_table, alter_table, insert,
update, inherit); fortunately those don't run concurrently.
Other than partitioning problems, most of the issues boil down to using
names like "foo", "bar", "tmp", etc, without thought for the fact that
other test scripts might use similar names concurrently. I've made an
effort to make all such names more specific.
One of the live hazards was that commit 7421f4b8 caused with.sql to
create a table named "test", conflicting with a similarly-named table
in alter_table.sql; this was exposed in the buildfarm recently.
The other one was that join.sql and transactions.sql both create tables
named "foo" and "bar"; but join.sql's uses of those names date back
only to December or so.
Since commit 7421f4b8 was back-patched to v10, back-patch a minimal
fix for that problem. The rest of this is just future-proofing.
Discussion: https://postgr.es/m/4627.1521070268@sss.pgh.pa.us
2018-03-15 17:08:51 -04:00
|
|
|
INSERT INTO withz SELECT i, 'insert'
|
Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint. DO NOTHING avoids the
constraint violation, without touching the pre-existing row. DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed. The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.
This feature is often referred to as upsert.
This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert. If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made. If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.
To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.
Bumps catversion as stored rules change.
Author: Peter Geoghegan, with significant contributions from Heikki
Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
Dean Rasheed, Stephen Frost and many others.
2015-05-07 23:31:36 -04:00
|
|
|
FROM generate_series(0, 16) i
|
Clean up duplicate table and function names in regression tests.
Many of the objects we create during the regression tests are put in the
public schema, so that using the same names in different regression tests
creates a hazard of test failures if any two such scripts run concurrently.
This patch cleans up a bunch of latent hazards of that sort, as well as two
live hazards.
The current situation in this regard is far worse than it was a year or two
back, because practically all of the partitioning-related test cases have
reused table names with enthusiasm. I despaired of cleaning up that mess
within the five most-affected tests (create_table, alter_table, insert,
update, inherit); fortunately those don't run concurrently.
Other than partitioning problems, most of the issues boil down to using
names like "foo", "bar", "tmp", etc, without thought for the fact that
other test scripts might use similar names concurrently. I've made an
effort to make all such names more specific.
One of the live hazards was that commit 7421f4b8 caused with.sql to
create a table named "test", conflicting with a similarly-named table
in alter_table.sql; this was exposed in the buildfarm recently.
The other one was that join.sql and transactions.sql both create tables
named "foo" and "bar"; but join.sql's uses of those names date back
only to December or so.
Since commit 7421f4b8 was back-patched to v10, back-patch a minimal
fix for that problem. The rest of this is just future-proofing.
Discussion: https://postgr.es/m/4627.1521070268@sss.pgh.pa.us
2018-03-15 17:08:51 -04:00
|
|
|
ON CONFLICT (k) DO UPDATE SET v = withz.v || ', now update'
|
Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint. DO NOTHING avoids the
constraint violation, without touching the pre-existing row. DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed. The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.
This feature is often referred to as upsert.
This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert. If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made. If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.
To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.
Bumps catversion as stored rules change.
Author: Peter Geoghegan, with significant contributions from Heikki
Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
Dean Rasheed, Stephen Frost and many others.
2015-05-07 23:31:36 -04:00
|
|
|
RETURNING *
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM t JOIN y ON t.k = y.a ORDER BY a, k;
|
|
|
|
|
|
|
|
|
|
-- Test EXCLUDED.* reference within CTE
|
|
|
|
|
WITH aa AS (
|
Clean up duplicate table and function names in regression tests.
Many of the objects we create during the regression tests are put in the
public schema, so that using the same names in different regression tests
creates a hazard of test failures if any two such scripts run concurrently.
This patch cleans up a bunch of latent hazards of that sort, as well as two
live hazards.
The current situation in this regard is far worse than it was a year or two
back, because practically all of the partitioning-related test cases have
reused table names with enthusiasm. I despaired of cleaning up that mess
within the five most-affected tests (create_table, alter_table, insert,
update, inherit); fortunately those don't run concurrently.
Other than partitioning problems, most of the issues boil down to using
names like "foo", "bar", "tmp", etc, without thought for the fact that
other test scripts might use similar names concurrently. I've made an
effort to make all such names more specific.
One of the live hazards was that commit 7421f4b8 caused with.sql to
create a table named "test", conflicting with a similarly-named table
in alter_table.sql; this was exposed in the buildfarm recently.
The other one was that join.sql and transactions.sql both create tables
named "foo" and "bar"; but join.sql's uses of those names date back
only to December or so.
Since commit 7421f4b8 was back-patched to v10, back-patch a minimal
fix for that problem. The rest of this is just future-proofing.
Discussion: https://postgr.es/m/4627.1521070268@sss.pgh.pa.us
2018-03-15 17:08:51 -04:00
|
|
|
INSERT INTO withz VALUES(1, 5) ON CONFLICT (k) DO UPDATE SET v = EXCLUDED.v
|
|
|
|
|
WHERE withz.k != EXCLUDED.k
|
Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint. DO NOTHING avoids the
constraint violation, without touching the pre-existing row. DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed. The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.
This feature is often referred to as upsert.
This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert. If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made. If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.
To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.
Bumps catversion as stored rules change.
Author: Peter Geoghegan, with significant contributions from Heikki
Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
Dean Rasheed, Stephen Frost and many others.
2015-05-07 23:31:36 -04:00
|
|
|
RETURNING *
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM aa;
|
|
|
|
|
|
|
|
|
|
-- New query/snapshot demonstrates side-effects of previous query.
|
Clean up duplicate table and function names in regression tests.
Many of the objects we create during the regression tests are put in the
public schema, so that using the same names in different regression tests
creates a hazard of test failures if any two such scripts run concurrently.
This patch cleans up a bunch of latent hazards of that sort, as well as two
live hazards.
The current situation in this regard is far worse than it was a year or two
back, because practically all of the partitioning-related test cases have
reused table names with enthusiasm. I despaired of cleaning up that mess
within the five most-affected tests (create_table, alter_table, insert,
update, inherit); fortunately those don't run concurrently.
Other than partitioning problems, most of the issues boil down to using
names like "foo", "bar", "tmp", etc, without thought for the fact that
other test scripts might use similar names concurrently. I've made an
effort to make all such names more specific.
One of the live hazards was that commit 7421f4b8 caused with.sql to
create a table named "test", conflicting with a similarly-named table
in alter_table.sql; this was exposed in the buildfarm recently.
The other one was that join.sql and transactions.sql both create tables
named "foo" and "bar"; but join.sql's uses of those names date back
only to December or so.
Since commit 7421f4b8 was back-patched to v10, back-patch a minimal
fix for that problem. The rest of this is just future-proofing.
Discussion: https://postgr.es/m/4627.1521070268@sss.pgh.pa.us
2018-03-15 17:08:51 -04:00
|
|
|
SELECT * FROM withz ORDER BY k;
|
Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint. DO NOTHING avoids the
constraint violation, without touching the pre-existing row. DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed. The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.
This feature is often referred to as upsert.
This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert. If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made. If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.
To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.
Bumps catversion as stored rules change.
Author: Peter Geoghegan, with significant contributions from Heikki
Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
Dean Rasheed, Stephen Frost and many others.
2015-05-07 23:31:36 -04:00
|
|
|
|
|
|
|
|
--
|
|
|
|
|
-- Ensure subqueries within the update clause work, even if they
|
|
|
|
|
-- reference outside values
|
|
|
|
|
--
|
|
|
|
|
WITH aa AS (SELECT 1 a, 2 b)
|
Clean up duplicate table and function names in regression tests.
Many of the objects we create during the regression tests are put in the
public schema, so that using the same names in different regression tests
creates a hazard of test failures if any two such scripts run concurrently.
This patch cleans up a bunch of latent hazards of that sort, as well as two
live hazards.
The current situation in this regard is far worse than it was a year or two
back, because practically all of the partitioning-related test cases have
reused table names with enthusiasm. I despaired of cleaning up that mess
within the five most-affected tests (create_table, alter_table, insert,
update, inherit); fortunately those don't run concurrently.
Other than partitioning problems, most of the issues boil down to using
names like "foo", "bar", "tmp", etc, without thought for the fact that
other test scripts might use similar names concurrently. I've made an
effort to make all such names more specific.
One of the live hazards was that commit 7421f4b8 caused with.sql to
create a table named "test", conflicting with a similarly-named table
in alter_table.sql; this was exposed in the buildfarm recently.
The other one was that join.sql and transactions.sql both create tables
named "foo" and "bar"; but join.sql's uses of those names date back
only to December or so.
Since commit 7421f4b8 was back-patched to v10, back-patch a minimal
fix for that problem. The rest of this is just future-proofing.
Discussion: https://postgr.es/m/4627.1521070268@sss.pgh.pa.us
2018-03-15 17:08:51 -04:00
|
|
|
INSERT INTO withz VALUES(1, 'insert')
|
Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint. DO NOTHING avoids the
constraint violation, without touching the pre-existing row. DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed. The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.
This feature is often referred to as upsert.
This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert. If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made. If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.
To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.
Bumps catversion as stored rules change.
Author: Peter Geoghegan, with significant contributions from Heikki
Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
Dean Rasheed, Stephen Frost and many others.
2015-05-07 23:31:36 -04:00
|
|
|
ON CONFLICT (k) DO UPDATE SET v = (SELECT b || ' update' FROM aa WHERE a = 1 LIMIT 1);
|
|
|
|
|
WITH aa AS (SELECT 1 a, 2 b)
|
Clean up duplicate table and function names in regression tests.
Many of the objects we create during the regression tests are put in the
public schema, so that using the same names in different regression tests
creates a hazard of test failures if any two such scripts run concurrently.
This patch cleans up a bunch of latent hazards of that sort, as well as two
live hazards.
The current situation in this regard is far worse than it was a year or two
back, because practically all of the partitioning-related test cases have
reused table names with enthusiasm. I despaired of cleaning up that mess
within the five most-affected tests (create_table, alter_table, insert,
update, inherit); fortunately those don't run concurrently.
Other than partitioning problems, most of the issues boil down to using
names like "foo", "bar", "tmp", etc, without thought for the fact that
other test scripts might use similar names concurrently. I've made an
effort to make all such names more specific.
One of the live hazards was that commit 7421f4b8 caused with.sql to
create a table named "test", conflicting with a similarly-named table
in alter_table.sql; this was exposed in the buildfarm recently.
The other one was that join.sql and transactions.sql both create tables
named "foo" and "bar"; but join.sql's uses of those names date back
only to December or so.
Since commit 7421f4b8 was back-patched to v10, back-patch a minimal
fix for that problem. The rest of this is just future-proofing.
Discussion: https://postgr.es/m/4627.1521070268@sss.pgh.pa.us
2018-03-15 17:08:51 -04:00
|
|
|
INSERT INTO withz VALUES(1, 'insert')
|
|
|
|
|
ON CONFLICT (k) DO UPDATE SET v = ' update' WHERE withz.k = (SELECT a FROM aa);
|
Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint. DO NOTHING avoids the
constraint violation, without touching the pre-existing row. DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed. The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.
This feature is often referred to as upsert.
This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert. If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made. If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.
To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.
Bumps catversion as stored rules change.
Author: Peter Geoghegan, with significant contributions from Heikki
Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
Dean Rasheed, Stephen Frost and many others.
2015-05-07 23:31:36 -04:00
|
|
|
WITH aa AS (SELECT 1 a, 2 b)
|
Clean up duplicate table and function names in regression tests.
Many of the objects we create during the regression tests are put in the
public schema, so that using the same names in different regression tests
creates a hazard of test failures if any two such scripts run concurrently.
This patch cleans up a bunch of latent hazards of that sort, as well as two
live hazards.
The current situation in this regard is far worse than it was a year or two
back, because practically all of the partitioning-related test cases have
reused table names with enthusiasm. I despaired of cleaning up that mess
within the five most-affected tests (create_table, alter_table, insert,
update, inherit); fortunately those don't run concurrently.
Other than partitioning problems, most of the issues boil down to using
names like "foo", "bar", "tmp", etc, without thought for the fact that
other test scripts might use similar names concurrently. I've made an
effort to make all such names more specific.
One of the live hazards was that commit 7421f4b8 caused with.sql to
create a table named "test", conflicting with a similarly-named table
in alter_table.sql; this was exposed in the buildfarm recently.
The other one was that join.sql and transactions.sql both create tables
named "foo" and "bar"; but join.sql's uses of those names date back
only to December or so.
Since commit 7421f4b8 was back-patched to v10, back-patch a minimal
fix for that problem. The rest of this is just future-proofing.
Discussion: https://postgr.es/m/4627.1521070268@sss.pgh.pa.us
2018-03-15 17:08:51 -04:00
|
|
|
INSERT INTO withz VALUES(1, 'insert')
|
Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint. DO NOTHING avoids the
constraint violation, without touching the pre-existing row. DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed. The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.
This feature is often referred to as upsert.
This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert. If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made. If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.
To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.
Bumps catversion as stored rules change.
Author: Peter Geoghegan, with significant contributions from Heikki
Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
Dean Rasheed, Stephen Frost and many others.
2015-05-07 23:31:36 -04:00
|
|
|
ON CONFLICT (k) DO UPDATE SET v = (SELECT b || ' update' FROM aa WHERE a = 1 LIMIT 1);
|
|
|
|
|
WITH aa AS (SELECT 'a' a, 'b' b UNION ALL SELECT 'a' a, 'b' b)
|
Clean up duplicate table and function names in regression tests.
Many of the objects we create during the regression tests are put in the
public schema, so that using the same names in different regression tests
creates a hazard of test failures if any two such scripts run concurrently.
This patch cleans up a bunch of latent hazards of that sort, as well as two
live hazards.
The current situation in this regard is far worse than it was a year or two
back, because practically all of the partitioning-related test cases have
reused table names with enthusiasm. I despaired of cleaning up that mess
within the five most-affected tests (create_table, alter_table, insert,
update, inherit); fortunately those don't run concurrently.
Other than partitioning problems, most of the issues boil down to using
names like "foo", "bar", "tmp", etc, without thought for the fact that
other test scripts might use similar names concurrently. I've made an
effort to make all such names more specific.
One of the live hazards was that commit 7421f4b8 caused with.sql to
create a table named "test", conflicting with a similarly-named table
in alter_table.sql; this was exposed in the buildfarm recently.
The other one was that join.sql and transactions.sql both create tables
named "foo" and "bar"; but join.sql's uses of those names date back
only to December or so.
Since commit 7421f4b8 was back-patched to v10, back-patch a minimal
fix for that problem. The rest of this is just future-proofing.
Discussion: https://postgr.es/m/4627.1521070268@sss.pgh.pa.us
2018-03-15 17:08:51 -04:00
|
|
|
INSERT INTO withz VALUES(1, 'insert')
|
Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint. DO NOTHING avoids the
constraint violation, without touching the pre-existing row. DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed. The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.
This feature is often referred to as upsert.
This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert. If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made. If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.
To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.
Bumps catversion as stored rules change.
Author: Peter Geoghegan, with significant contributions from Heikki
Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
Dean Rasheed, Stephen Frost and many others.
2015-05-07 23:31:36 -04:00
|
|
|
ON CONFLICT (k) DO UPDATE SET v = (SELECT b || ' update' FROM aa WHERE a = 'a' LIMIT 1);
|
|
|
|
|
WITH aa AS (SELECT 1 a, 2 b)
|
Clean up duplicate table and function names in regression tests.
Many of the objects we create during the regression tests are put in the
public schema, so that using the same names in different regression tests
creates a hazard of test failures if any two such scripts run concurrently.
This patch cleans up a bunch of latent hazards of that sort, as well as two
live hazards.
The current situation in this regard is far worse than it was a year or two
back, because practically all of the partitioning-related test cases have
reused table names with enthusiasm. I despaired of cleaning up that mess
within the five most-affected tests (create_table, alter_table, insert,
update, inherit); fortunately those don't run concurrently.
Other than partitioning problems, most of the issues boil down to using
names like "foo", "bar", "tmp", etc, without thought for the fact that
other test scripts might use similar names concurrently. I've made an
effort to make all such names more specific.
One of the live hazards was that commit 7421f4b8 caused with.sql to
create a table named "test", conflicting with a similarly-named table
in alter_table.sql; this was exposed in the buildfarm recently.
The other one was that join.sql and transactions.sql both create tables
named "foo" and "bar"; but join.sql's uses of those names date back
only to December or so.
Since commit 7421f4b8 was back-patched to v10, back-patch a minimal
fix for that problem. The rest of this is just future-proofing.
Discussion: https://postgr.es/m/4627.1521070268@sss.pgh.pa.us
2018-03-15 17:08:51 -04:00
|
|
|
INSERT INTO withz VALUES(1, (SELECT b || ' insert' FROM aa WHERE a = 1 ))
|
Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint. DO NOTHING avoids the
constraint violation, without touching the pre-existing row. DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed. The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.
This feature is often referred to as upsert.
This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert. If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made. If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.
To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.
Bumps catversion as stored rules change.
Author: Peter Geoghegan, with significant contributions from Heikki
Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
Dean Rasheed, Stephen Frost and many others.
2015-05-07 23:31:36 -04:00
|
|
|
ON CONFLICT (k) DO UPDATE SET v = (SELECT b || ' update' FROM aa WHERE a = 1 LIMIT 1);
|
|
|
|
|
|
Fix ON CONFLICT UPDATE bug breaking AFTER UPDATE triggers.
ExecOnConflictUpdate() passed t_ctid of the to-be-updated tuple to
ExecUpdate(). That's problematic primarily because of two reason: First
and foremost t_ctid could point to a different tuple. Secondly, and
that's what triggered the complaint by Stanislav, t_ctid is changed by
heap_update() to point to the new tuple version. The behavior of AFTER
UPDATE triggers was therefore broken, with NEW.* and OLD.* tuples
spuriously identical within AFTER UPDATE triggers.
To fix both issues, pass a pointer to t_self of a on-stack HeapTuple
instead.
Fixing this bug lead to one change in regression tests, which previously
failed due to the first issue mentioned above. There's a reasonable
expectation that test fails, as it updates one row repeatedly within one
INSERT ... ON CONFLICT statement. That is only possible if the second
update is triggered via ON CONFLICT ... SET, ON CONFLICT ... WHERE, or
by a WITH CHECK expression, as those are executed after
ExecOnConflictUpdate() does a visibility check. That could easily be
prohibited, but given it's allowed for plain UPDATEs and a rare corner
case, it doesn't seem worthwhile.
Reported-By: Stanislav Grozev
Author: Andres Freund and Peter Geoghegan
Discussion: CAA78GVqy1+LisN-8DygekD_Ldfy=BJLarSpjGhytOsgkpMavfQ@mail.gmail.com
Backpatch: 9.5, where ON CONFLICT was introduced
2015-12-10 10:26:45 -05:00
|
|
|
-- Update a row more than once, in different parts of a wCTE. That is
|
|
|
|
|
-- an allowed, presumably very rare, edge case, but since it was
|
|
|
|
|
-- broken in the past, having a test seems worthwhile.
|
Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint. DO NOTHING avoids the
constraint violation, without touching the pre-existing row. DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed. The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.
This feature is often referred to as upsert.
This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert. If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made. If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.
To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.
Bumps catversion as stored rules change.
Author: Peter Geoghegan, with significant contributions from Heikki
Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
Dean Rasheed, Stephen Frost and many others.
2015-05-07 23:31:36 -04:00
|
|
|
WITH simpletup AS (
|
|
|
|
|
SELECT 2 k, 'Green' v),
|
|
|
|
|
upsert_cte AS (
|
Clean up duplicate table and function names in regression tests.
Many of the objects we create during the regression tests are put in the
public schema, so that using the same names in different regression tests
creates a hazard of test failures if any two such scripts run concurrently.
This patch cleans up a bunch of latent hazards of that sort, as well as two
live hazards.
The current situation in this regard is far worse than it was a year or two
back, because practically all of the partitioning-related test cases have
reused table names with enthusiasm. I despaired of cleaning up that mess
within the five most-affected tests (create_table, alter_table, insert,
update, inherit); fortunately those don't run concurrently.
Other than partitioning problems, most of the issues boil down to using
names like "foo", "bar", "tmp", etc, without thought for the fact that
other test scripts might use similar names concurrently. I've made an
effort to make all such names more specific.
One of the live hazards was that commit 7421f4b8 caused with.sql to
create a table named "test", conflicting with a similarly-named table
in alter_table.sql; this was exposed in the buildfarm recently.
The other one was that join.sql and transactions.sql both create tables
named "foo" and "bar"; but join.sql's uses of those names date back
only to December or so.
Since commit 7421f4b8 was back-patched to v10, back-patch a minimal
fix for that problem. The rest of this is just future-proofing.
Discussion: https://postgr.es/m/4627.1521070268@sss.pgh.pa.us
2018-03-15 17:08:51 -04:00
|
|
|
INSERT INTO withz VALUES(2, 'Blue') ON CONFLICT (k) DO
|
|
|
|
|
UPDATE SET (k, v) = (SELECT k, v FROM simpletup WHERE simpletup.k = withz.k)
|
Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint. DO NOTHING avoids the
constraint violation, without touching the pre-existing row. DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed. The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.
This feature is often referred to as upsert.
This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert. If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made. If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.
To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.
Bumps catversion as stored rules change.
Author: Peter Geoghegan, with significant contributions from Heikki
Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
Dean Rasheed, Stephen Frost and many others.
2015-05-07 23:31:36 -04:00
|
|
|
RETURNING k, v)
|
Clean up duplicate table and function names in regression tests.
Many of the objects we create during the regression tests are put in the
public schema, so that using the same names in different regression tests
creates a hazard of test failures if any two such scripts run concurrently.
This patch cleans up a bunch of latent hazards of that sort, as well as two
live hazards.
The current situation in this regard is far worse than it was a year or two
back, because practically all of the partitioning-related test cases have
reused table names with enthusiasm. I despaired of cleaning up that mess
within the five most-affected tests (create_table, alter_table, insert,
update, inherit); fortunately those don't run concurrently.
Other than partitioning problems, most of the issues boil down to using
names like "foo", "bar", "tmp", etc, without thought for the fact that
other test scripts might use similar names concurrently. I've made an
effort to make all such names more specific.
One of the live hazards was that commit 7421f4b8 caused with.sql to
create a table named "test", conflicting with a similarly-named table
in alter_table.sql; this was exposed in the buildfarm recently.
The other one was that join.sql and transactions.sql both create tables
named "foo" and "bar"; but join.sql's uses of those names date back
only to December or so.
Since commit 7421f4b8 was back-patched to v10, back-patch a minimal
fix for that problem. The rest of this is just future-proofing.
Discussion: https://postgr.es/m/4627.1521070268@sss.pgh.pa.us
2018-03-15 17:08:51 -04:00
|
|
|
INSERT INTO withz VALUES(2, 'Red') ON CONFLICT (k) DO
|
|
|
|
|
UPDATE SET (k, v) = (SELECT k, v FROM upsert_cte WHERE upsert_cte.k = withz.k)
|
Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint. DO NOTHING avoids the
constraint violation, without touching the pre-existing row. DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed. The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.
This feature is often referred to as upsert.
This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert. If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made. If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.
To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.
Bumps catversion as stored rules change.
Author: Peter Geoghegan, with significant contributions from Heikki
Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
Dean Rasheed, Stephen Frost and many others.
2015-05-07 23:31:36 -04:00
|
|
|
RETURNING k, v;
|
|
|
|
|
|
Clean up duplicate table and function names in regression tests.
Many of the objects we create during the regression tests are put in the
public schema, so that using the same names in different regression tests
creates a hazard of test failures if any two such scripts run concurrently.
This patch cleans up a bunch of latent hazards of that sort, as well as two
live hazards.
The current situation in this regard is far worse than it was a year or two
back, because practically all of the partitioning-related test cases have
reused table names with enthusiasm. I despaired of cleaning up that mess
within the five most-affected tests (create_table, alter_table, insert,
update, inherit); fortunately those don't run concurrently.
Other than partitioning problems, most of the issues boil down to using
names like "foo", "bar", "tmp", etc, without thought for the fact that
other test scripts might use similar names concurrently. I've made an
effort to make all such names more specific.
One of the live hazards was that commit 7421f4b8 caused with.sql to
create a table named "test", conflicting with a similarly-named table
in alter_table.sql; this was exposed in the buildfarm recently.
The other one was that join.sql and transactions.sql both create tables
named "foo" and "bar"; but join.sql's uses of those names date back
only to December or so.
Since commit 7421f4b8 was back-patched to v10, back-patch a minimal
fix for that problem. The rest of this is just future-proofing.
Discussion: https://postgr.es/m/4627.1521070268@sss.pgh.pa.us
2018-03-15 17:08:51 -04:00
|
|
|
DROP TABLE withz;
|
Add support for INSERT ... ON CONFLICT DO NOTHING/UPDATE.
The newly added ON CONFLICT clause allows to specify an alternative to
raising a unique or exclusion constraint violation error when inserting.
ON CONFLICT refers to constraints that can either be specified using a
inference clause (by specifying the columns of a unique constraint) or
by naming a unique or exclusion constraint. DO NOTHING avoids the
constraint violation, without touching the pre-existing row. DO UPDATE
SET ... [WHERE ...] updates the pre-existing tuple, and has access to
both the tuple proposed for insertion and the existing tuple; the
optional WHERE clause can be used to prevent an update from being
executed. The UPDATE SET and WHERE clauses have access to the tuple
proposed for insertion using the "magic" EXCLUDED alias, and to the
pre-existing tuple using the table name or its alias.
This feature is often referred to as upsert.
This is implemented using a new infrastructure called "speculative
insertion". It is an optimistic variant of regular insertion that first
does a pre-check for existing tuples and then attempts an insert. If a
violating tuple was inserted concurrently, the speculatively inserted
tuple is deleted and a new attempt is made. If the pre-check finds a
matching tuple the alternative DO NOTHING or DO UPDATE action is taken.
If the insertion succeeds without detecting a conflict, the tuple is
deemed inserted.
To handle the possible ambiguity between the excluded alias and a table
named excluded, and for convenience with long relation names, INSERT
INTO now can alias its target table.
Bumps catversion as stored rules change.
Author: Peter Geoghegan, with significant contributions from Heikki
Linnakangas and Andres Freund. Testing infrastructure by Jeff Janes.
Reviewed-By: Heikki Linnakangas, Andres Freund, Robert Haas, Simon Riggs,
Dean Rasheed, Stephen Frost and many others.
2015-05-07 23:31:36 -04:00
|
|
|
|
2022-03-28 10:45:58 -04:00
|
|
|
-- 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);
|
|
|
|
|
|
|
|
|
|
-- Basic:
|
|
|
|
|
WITH cte_basic AS MATERIALIZED (SELECT 1 a, 'cte_basic val' b)
|
|
|
|
|
MERGE INTO m USING (select 0 k, 'merge source SubPlan' v offset 0) 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;
|
|
|
|
|
|
|
|
|
|
-- See EXPLAIN output for same query:
|
|
|
|
|
EXPLAIN (VERBOSE, COSTS OFF)
|
|
|
|
|
WITH cte_basic AS MATERIALIZED (SELECT 1 a, 'cte_basic val' b)
|
|
|
|
|
MERGE INTO m USING (select 0 k, 'merge source SubPlan' v offset 0) 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);
|
|
|
|
|
|
|
|
|
|
-- InitPlan
|
|
|
|
|
WITH cte_init AS MATERIALIZED (SELECT 1 a, 'cte_init val' b)
|
|
|
|
|
MERGE INTO m USING (select 1 k, 'merge source InitPlan' v offset 0) 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;
|
|
|
|
|
|
|
|
|
|
-- See EXPLAIN output for same query:
|
|
|
|
|
EXPLAIN (VERBOSE, COSTS OFF)
|
|
|
|
|
WITH cte_init AS MATERIALIZED (SELECT 1 a, 'cte_init val' b)
|
|
|
|
|
MERGE INTO m USING (select 1 k, 'merge source InitPlan' v offset 0) 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);
|
|
|
|
|
|
|
|
|
|
-- MERGE source comes from CTE:
|
|
|
|
|
WITH merge_source_cte AS MATERIALIZED (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;
|
|
|
|
|
|
|
|
|
|
-- See EXPLAIN output for same query:
|
|
|
|
|
EXPLAIN (VERBOSE, COSTS OFF)
|
|
|
|
|
WITH merge_source_cte AS MATERIALIZED (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));
|
|
|
|
|
|
|
|
|
|
DROP TABLE m;
|
|
|
|
|
|
2011-02-25 23:53:34 -05:00
|
|
|
-- check that run to completion happens in proper ordering
|
|
|
|
|
|
|
|
|
|
TRUNCATE TABLE y;
|
|
|
|
|
INSERT INTO y SELECT generate_series(1, 3);
|
|
|
|
|
CREATE TEMPORARY TABLE yy (a INTEGER);
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE t1 AS (
|
|
|
|
|
INSERT INTO y SELECT * FROM y RETURNING *
|
|
|
|
|
), t2 AS (
|
|
|
|
|
INSERT INTO yy SELECT * FROM t1 RETURNING *
|
|
|
|
|
)
|
|
|
|
|
SELECT 1;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM y;
|
|
|
|
|
SELECT * FROM yy;
|
|
|
|
|
|
|
|
|
|
WITH RECURSIVE t1 AS (
|
|
|
|
|
INSERT INTO yy SELECT * FROM t2 RETURNING *
|
|
|
|
|
), t2 AS (
|
|
|
|
|
INSERT INTO y SELECT * FROM y RETURNING *
|
|
|
|
|
)
|
|
|
|
|
SELECT 1;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM y;
|
|
|
|
|
SELECT * FROM yy;
|
|
|
|
|
|
2011-02-25 18:56:23 -05:00
|
|
|
-- triggers
|
|
|
|
|
|
|
|
|
|
TRUNCATE TABLE y;
|
|
|
|
|
INSERT INTO y SELECT generate_series(1, 10);
|
|
|
|
|
|
|
|
|
|
CREATE FUNCTION y_trigger() RETURNS trigger AS $$
|
|
|
|
|
begin
|
|
|
|
|
raise notice 'y_trigger: a = %', new.a;
|
|
|
|
|
return new;
|
|
|
|
|
end;
|
|
|
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
|
|
|
|
|
|
CREATE TRIGGER y_trig BEFORE INSERT ON y FOR EACH ROW
|
|
|
|
|
EXECUTE PROCEDURE y_trigger();
|
|
|
|
|
|
|
|
|
|
WITH t AS (
|
|
|
|
|
INSERT INTO y
|
|
|
|
|
VALUES
|
|
|
|
|
(21),
|
|
|
|
|
(22),
|
|
|
|
|
(23)
|
|
|
|
|
RETURNING *
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM t;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM y;
|
|
|
|
|
|
|
|
|
|
DROP TRIGGER y_trig ON y;
|
|
|
|
|
|
|
|
|
|
CREATE TRIGGER y_trig AFTER INSERT ON y FOR EACH ROW
|
|
|
|
|
EXECUTE PROCEDURE y_trigger();
|
|
|
|
|
|
|
|
|
|
WITH t AS (
|
|
|
|
|
INSERT INTO y
|
|
|
|
|
VALUES
|
|
|
|
|
(31),
|
|
|
|
|
(32),
|
|
|
|
|
(33)
|
|
|
|
|
RETURNING *
|
|
|
|
|
)
|
2011-02-27 13:43:29 -05:00
|
|
|
SELECT * FROM t LIMIT 1;
|
2011-02-25 18:56:23 -05:00
|
|
|
|
|
|
|
|
SELECT * FROM y;
|
|
|
|
|
|
|
|
|
|
DROP TRIGGER y_trig ON y;
|
|
|
|
|
|
|
|
|
|
CREATE OR REPLACE FUNCTION y_trigger() RETURNS trigger AS $$
|
|
|
|
|
begin
|
|
|
|
|
raise notice 'y_trigger';
|
|
|
|
|
return null;
|
|
|
|
|
end;
|
|
|
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
|
|
|
|
|
|
CREATE TRIGGER y_trig AFTER INSERT ON y FOR EACH STATEMENT
|
|
|
|
|
EXECUTE PROCEDURE y_trigger();
|
|
|
|
|
|
|
|
|
|
WITH t AS (
|
|
|
|
|
INSERT INTO y
|
|
|
|
|
VALUES
|
|
|
|
|
(41),
|
|
|
|
|
(42),
|
|
|
|
|
(43)
|
|
|
|
|
RETURNING *
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM t;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM y;
|
|
|
|
|
|
|
|
|
|
DROP TRIGGER y_trig ON y;
|
|
|
|
|
DROP FUNCTION y_trigger();
|
|
|
|
|
|
2012-01-28 20:24:42 -05:00
|
|
|
-- WITH attached to inherited UPDATE or DELETE
|
|
|
|
|
|
|
|
|
|
CREATE TEMP TABLE parent ( id int, val text );
|
|
|
|
|
CREATE TEMP TABLE child1 ( ) INHERITS ( parent );
|
|
|
|
|
CREATE TEMP TABLE child2 ( ) INHERITS ( parent );
|
|
|
|
|
|
|
|
|
|
INSERT INTO parent VALUES ( 1, 'p1' );
|
|
|
|
|
INSERT INTO child1 VALUES ( 11, 'c11' ),( 12, 'c12' );
|
|
|
|
|
INSERT INTO child2 VALUES ( 23, 'c21' ),( 24, 'c22' );
|
|
|
|
|
|
|
|
|
|
WITH rcte AS ( SELECT sum(id) AS totalid FROM parent )
|
|
|
|
|
UPDATE parent SET id = id + totalid FROM rcte;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM parent;
|
|
|
|
|
|
|
|
|
|
WITH wcte AS ( INSERT INTO child1 VALUES ( 42, 'new' ) RETURNING id AS newid )
|
|
|
|
|
UPDATE parent SET id = id + newid FROM wcte;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM parent;
|
|
|
|
|
|
|
|
|
|
WITH rcte AS ( SELECT max(id) AS maxid FROM parent )
|
|
|
|
|
DELETE FROM parent USING rcte WHERE id = maxid;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM parent;
|
|
|
|
|
|
|
|
|
|
WITH wcte AS ( INSERT INTO child2 VALUES ( 42, 'new2' ) RETURNING id AS newid )
|
|
|
|
|
DELETE FROM parent USING wcte WHERE id = newid;
|
|
|
|
|
|
|
|
|
|
SELECT * FROM parent;
|
|
|
|
|
|
Fix planner's handling of RETURNING lists in writable CTEs.
setrefs.c failed to do "rtoffset" adjustment of Vars in RETURNING lists,
which meant they were left with the wrong varnos when the RETURNING list
was in a subquery. That was never possible before writable CTEs, of
course, but now it's broken. The executor fails to notice any problem
because ExecEvalVar just references the ecxt_scantuple for any normal
varno; but EXPLAIN breaks when the varno is wrong, as illustrated in a
recent complaint from Bartosz Dmytrak.
Since the eventual rtoffset of the subquery is not known at the time
we are preparing its plan node, the previous scheme of executing
set_returning_clause_references() at that time cannot handle this
adjustment. Fortunately, it turns out that we don't really need to do it
that way, because all the needed information is available during normal
setrefs.c execution; we just have to dig it out of the ModifyTable node.
So, do that, and get rid of the kluge of early setrefs processing of
RETURNING lists. (This is a little bit of a cheat in the case of inherited
UPDATE/DELETE, because we are not passing a "root" struct that corresponds
exactly to what the subplan was built with. But that doesn't matter, and
anyway this is less ugly than early setrefs processing was.)
Back-patch to 9.1, where the problem became possible to hit.
2012-04-25 20:20:33 -04:00
|
|
|
-- check EXPLAIN VERBOSE for a wCTE with RETURNING
|
|
|
|
|
|
|
|
|
|
EXPLAIN (VERBOSE, COSTS OFF)
|
|
|
|
|
WITH wcte AS ( INSERT INTO int8_tbl VALUES ( 42, 47 ) RETURNING q2 )
|
2022-02-08 15:30:38 -05:00
|
|
|
DELETE FROM a_star USING wcte WHERE aa = q2;
|
Fix planner's handling of RETURNING lists in writable CTEs.
setrefs.c failed to do "rtoffset" adjustment of Vars in RETURNING lists,
which meant they were left with the wrong varnos when the RETURNING list
was in a subquery. That was never possible before writable CTEs, of
course, but now it's broken. The executor fails to notice any problem
because ExecEvalVar just references the ecxt_scantuple for any normal
varno; but EXPLAIN breaks when the varno is wrong, as illustrated in a
recent complaint from Bartosz Dmytrak.
Since the eventual rtoffset of the subquery is not known at the time
we are preparing its plan node, the previous scheme of executing
set_returning_clause_references() at that time cannot handle this
adjustment. Fortunately, it turns out that we don't really need to do it
that way, because all the needed information is available during normal
setrefs.c execution; we just have to dig it out of the ModifyTable node.
So, do that, and get rid of the kluge of early setrefs processing of
RETURNING lists. (This is a little bit of a cheat in the case of inherited
UPDATE/DELETE, because we are not passing a "root" struct that corresponds
exactly to what the subplan was built with. But that doesn't matter, and
anyway this is less ugly than early setrefs processing was.)
Back-patch to 9.1, where the problem became possible to hit.
2012-04-25 20:20:33 -04:00
|
|
|
|
2011-02-25 18:56:23 -05:00
|
|
|
-- error cases
|
|
|
|
|
|
|
|
|
|
-- data-modifying WITH tries to use its own output
|
|
|
|
|
WITH RECURSIVE t AS (
|
|
|
|
|
INSERT INTO y
|
|
|
|
|
SELECT * FROM t
|
|
|
|
|
)
|
|
|
|
|
VALUES(FALSE);
|
|
|
|
|
|
|
|
|
|
-- no RETURNING in a referenced data-modifying WITH
|
|
|
|
|
WITH t AS (
|
|
|
|
|
INSERT INTO y VALUES(0)
|
|
|
|
|
)
|
|
|
|
|
SELECT * FROM t;
|
|
|
|
|
|
|
|
|
|
-- data-modifying WITH allowed only at the top level
|
|
|
|
|
SELECT * FROM (
|
|
|
|
|
WITH t AS (UPDATE y SET a=a+1 RETURNING *)
|
|
|
|
|
SELECT * FROM t
|
|
|
|
|
) ss;
|
|
|
|
|
|
|
|
|
|
-- most variants of rules aren't allowed
|
|
|
|
|
CREATE RULE y_rule AS ON INSERT TO y WHERE a=0 DO INSTEAD DELETE FROM y;
|
|
|
|
|
WITH t AS (
|
|
|
|
|
INSERT INTO y VALUES(0)
|
|
|
|
|
)
|
|
|
|
|
VALUES(FALSE);
|
2021-07-09 11:02:26 -04:00
|
|
|
CREATE OR REPLACE RULE y_rule AS ON INSERT TO y DO INSTEAD NOTHING;
|
|
|
|
|
WITH t AS (
|
|
|
|
|
INSERT INTO y VALUES(0)
|
|
|
|
|
)
|
|
|
|
|
VALUES(FALSE);
|
|
|
|
|
CREATE OR REPLACE RULE y_rule AS ON INSERT TO y DO INSTEAD NOTIFY foo;
|
|
|
|
|
WITH t AS (
|
|
|
|
|
INSERT INTO y VALUES(0)
|
|
|
|
|
)
|
|
|
|
|
VALUES(FALSE);
|
|
|
|
|
CREATE OR REPLACE RULE y_rule AS ON INSERT TO y DO ALSO NOTIFY foo;
|
|
|
|
|
WITH t AS (
|
|
|
|
|
INSERT INTO y VALUES(0)
|
|
|
|
|
)
|
|
|
|
|
VALUES(FALSE);
|
|
|
|
|
CREATE OR REPLACE RULE y_rule AS ON INSERT TO y
|
|
|
|
|
DO INSTEAD (NOTIFY foo; NOTIFY bar);
|
|
|
|
|
WITH t AS (
|
|
|
|
|
INSERT INTO y VALUES(0)
|
|
|
|
|
)
|
|
|
|
|
VALUES(FALSE);
|
2011-02-25 18:56:23 -05:00
|
|
|
DROP RULE y_rule ON y;
|
Improve parser's one-extra-token lookahead mechanism.
There are a couple of places in our grammar that fail to be strict LALR(1),
by requiring more than a single token of lookahead to decide what to do.
Up to now we've dealt with that by using a filter between the lexer and
parser that merges adjacent tokens into one in the places where two tokens
of lookahead are necessary. But that creates a number of user-visible
anomalies, for instance that you can't name a CTE "ordinality" because
"WITH ordinality AS ..." triggers folding of WITH and ORDINALITY into one
token. I realized that there's a better way.
In this patch, we still do the lookahead basically as before, but we never
merge the second token into the first; we replace just the first token by
a special lookahead symbol when one of the lookahead pairs is seen.
This requires a couple extra productions in the grammar, but it involves
fewer special tokens, so that the grammar tables come out a bit smaller
than before. The filter logic is no slower than before, perhaps a bit
faster.
I also fixed the filter logic so that when backing up after a lookahead,
the current token's terminator is correctly restored; this eliminates some
weird behavior in error message issuance, as is shown by the one change in
existing regression test outputs.
I believe that this patch entirely eliminates odd behaviors caused by
lookahead for WITH. It doesn't really improve the situation for NULLS
followed by FIRST/LAST unfortunately: those sequences still act like a
reserved word, even though there are cases where they should be seen as two
ordinary identifiers, eg "SELECT nulls first FROM ...". I experimented
with additional grammar hacks but couldn't find any simple solution for
that. Still, this is better than before, and it seems much more likely
that we *could* somehow solve the NULLS case on the basis of this filter
behavior than the previous one.
2015-02-24 17:53:42 -05:00
|
|
|
|
|
|
|
|
-- check that parser lookahead for WITH doesn't cause any odd behavior
|
|
|
|
|
create table foo (with baz); -- fail, WITH is a reserved word
|
|
|
|
|
create table foo (with ordinality); -- fail, WITH is a reserved word
|
|
|
|
|
with ordinality as (select 1 as x) select * from ordinality;
|
2017-04-01 00:17:18 -04:00
|
|
|
|
|
|
|
|
-- check sane response to attempt to modify CTE relation
|
2021-12-29 22:09:53 -05:00
|
|
|
WITH with_test AS (SELECT 42) INSERT INTO with_test VALUES (1);
|
Fix incorrect handling of CTEs and ENRs as DML target relations.
setTargetTable threw an error if the proposed target RangeVar's relname
matched any visible CTE or ENR. This breaks backwards compatibility in
the CTE case, since pre-v10 we never looked for a CTE here at all, so that
CTE names did not mask regular tables. It does seem like a good idea to
throw an error for the ENR case, though, thus causing ENRs to mask tables
for this purpose; ENRs are new in v10 so we're not breaking existing code,
and we may someday want to allow them to be the targets of DML.
To fix that, replace use of getRTEForSpecialRelationTypes, which was
overkill anyway, with use of scanNameSpaceForENR.
A second problem was that the check neglected to verify null schemaname,
so that a CTE or ENR could incorrectly be thought to match a qualified
RangeVar. That happened because getRTEForSpecialRelationTypes relied
on its caller to have checked for null schemaname. Even though the one
remaining caller got it right, this is obviously bug-prone, so move
the check inside getRTEForSpecialRelationTypes.
Also, revert commit 18ce3a4ab's extremely poorly thought out decision to
add a NULL return case to parserOpenTable --- without either documenting
that or adjusting any of the callers to check for it. The current bug
seems to have arisen in part due to working around that bad idea.
In passing, remove the one-line shim functions transformCTEReference and
transformENRReference --- they don't seem to be adding any clarity or
functionality.
Per report from Hugo Mercier (via Julien Rouhaud). Back-patch to v10
where the bug was introduced.
Thomas Munro, with minor editing by me
Discussion: https://postgr.es/m/CAOBaU_YdPVH+PTtiKSSLOiiW3mVDYsnNUekK+XPbHXiP=wrFLA@mail.gmail.com
2017-10-16 17:56:42 -04:00
|
|
|
|
|
|
|
|
-- check response to attempt to modify table with same name as a CTE (perhaps
|
|
|
|
|
-- surprisingly it works, because CTEs don't hide tables from data-modifying
|
|
|
|
|
-- statements)
|
2021-12-29 22:09:53 -05:00
|
|
|
create temp table with_test (i int);
|
|
|
|
|
with with_test as (select 42) insert into with_test select * from with_test;
|
|
|
|
|
select * from with_test;
|
|
|
|
|
drop table with_test;
|