mirror of
https://github.com/postgres/postgres.git
synced 2025-07-28 23:42:10 +03:00
Support parameterized TidPaths.
Up to now we've not worried much about joins where the join key is a relation's CTID column, reasoning that storing a table's CTIDs in some other table would be pretty useless. However, there are use-cases for this sort of query involving self-joins, so that argument doesn't really hold water. This patch allows generating plans for joins on CTID that use a nestloop with inner TidScan, similar to what we might do with an index on the join column. This is the most efficient way to join when the outer side of the nestloop is expected to yield relatively few rows. This change requires upgrading tidpath.c and the generated TidPaths to work with RestrictInfos instead of bare qual clauses, but that's long-postponed technical debt anyway. Discussion: https://postgr.es/m/17443.1545435266@sss.pgh.pa.us
This commit is contained in:
@ -40,6 +40,22 @@ SELECT ctid, * FROM tidscan WHERE '(0,1)' = ctid;
|
||||
(0,1) | 1
|
||||
(1 row)
|
||||
|
||||
-- OR'd clauses
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT ctid, * FROM tidscan WHERE ctid = '(0,2)' OR '(0,1)' = ctid;
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------------
|
||||
Tid Scan on tidscan
|
||||
TID Cond: ((ctid = '(0,2)'::tid) OR ('(0,1)'::tid = ctid))
|
||||
(2 rows)
|
||||
|
||||
SELECT ctid, * FROM tidscan WHERE ctid = '(0,2)' OR '(0,1)' = ctid;
|
||||
ctid | id
|
||||
-------+----
|
||||
(0,1) | 1
|
||||
(0,2) | 2
|
||||
(2 rows)
|
||||
|
||||
-- ctid = ScalarArrayOp - implemented as tidscan
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT ctid, * FROM tidscan WHERE ctid = ANY(ARRAY['(0,1)', '(0,2)']::tid[]);
|
||||
@ -92,6 +108,45 @@ WHERE (id = 3 AND ctid IN ('(0,2)', '(0,3)')) OR (ctid = '(0,1)' AND id = 1);
|
||||
(0,3) | 3
|
||||
(2 rows)
|
||||
|
||||
-- nestloop-with-inner-tidscan joins on tid
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT t1.ctid, t1.*, t2.ctid, t2.*
|
||||
FROM tidscan t1 JOIN tidscan t2 ON t1.ctid = t2.ctid WHERE t1.id = 1;
|
||||
QUERY PLAN
|
||||
------------------------------------
|
||||
Nested Loop
|
||||
-> Seq Scan on tidscan t1
|
||||
Filter: (id = 1)
|
||||
-> Tid Scan on tidscan t2
|
||||
TID Cond: (ctid = t1.ctid)
|
||||
(5 rows)
|
||||
|
||||
SELECT t1.ctid, t1.*, t2.ctid, t2.*
|
||||
FROM tidscan t1 JOIN tidscan t2 ON t1.ctid = t2.ctid WHERE t1.id = 1;
|
||||
ctid | id | ctid | id
|
||||
-------+----+-------+----
|
||||
(0,1) | 1 | (0,1) | 1
|
||||
(1 row)
|
||||
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT t1.ctid, t1.*, t2.ctid, t2.*
|
||||
FROM tidscan t1 LEFT JOIN tidscan t2 ON t1.ctid = t2.ctid WHERE t1.id = 1;
|
||||
QUERY PLAN
|
||||
------------------------------------
|
||||
Nested Loop Left Join
|
||||
-> Seq Scan on tidscan t1
|
||||
Filter: (id = 1)
|
||||
-> Tid Scan on tidscan t2
|
||||
TID Cond: (t1.ctid = ctid)
|
||||
(5 rows)
|
||||
|
||||
SELECT t1.ctid, t1.*, t2.ctid, t2.*
|
||||
FROM tidscan t1 LEFT JOIN tidscan t2 ON t1.ctid = t2.ctid WHERE t1.id = 1;
|
||||
ctid | id | ctid | id
|
||||
-------+----+-------+----
|
||||
(0,1) | 1 | (0,1) | 1
|
||||
(1 row)
|
||||
|
||||
-- exercise backward scan and rewind
|
||||
BEGIN;
|
||||
DECLARE c CURSOR FOR
|
||||
|
@ -17,6 +17,11 @@ EXPLAIN (COSTS OFF)
|
||||
SELECT ctid, * FROM tidscan WHERE '(0,1)' = ctid;
|
||||
SELECT ctid, * FROM tidscan WHERE '(0,1)' = ctid;
|
||||
|
||||
-- OR'd clauses
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT ctid, * FROM tidscan WHERE ctid = '(0,2)' OR '(0,1)' = ctid;
|
||||
SELECT ctid, * FROM tidscan WHERE ctid = '(0,2)' OR '(0,1)' = ctid;
|
||||
|
||||
-- ctid = ScalarArrayOp - implemented as tidscan
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT ctid, * FROM tidscan WHERE ctid = ANY(ARRAY['(0,1)', '(0,2)']::tid[]);
|
||||
@ -34,6 +39,18 @@ WHERE (id = 3 AND ctid IN ('(0,2)', '(0,3)')) OR (ctid = '(0,1)' AND id = 1);
|
||||
SELECT ctid, * FROM tidscan
|
||||
WHERE (id = 3 AND ctid IN ('(0,2)', '(0,3)')) OR (ctid = '(0,1)' AND id = 1);
|
||||
|
||||
-- nestloop-with-inner-tidscan joins on tid
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT t1.ctid, t1.*, t2.ctid, t2.*
|
||||
FROM tidscan t1 JOIN tidscan t2 ON t1.ctid = t2.ctid WHERE t1.id = 1;
|
||||
SELECT t1.ctid, t1.*, t2.ctid, t2.*
|
||||
FROM tidscan t1 JOIN tidscan t2 ON t1.ctid = t2.ctid WHERE t1.id = 1;
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT t1.ctid, t1.*, t2.ctid, t2.*
|
||||
FROM tidscan t1 LEFT JOIN tidscan t2 ON t1.ctid = t2.ctid WHERE t1.id = 1;
|
||||
SELECT t1.ctid, t1.*, t2.ctid, t2.*
|
||||
FROM tidscan t1 LEFT JOIN tidscan t2 ON t1.ctid = t2.ctid WHERE t1.id = 1;
|
||||
|
||||
-- exercise backward scan and rewind
|
||||
BEGIN;
|
||||
DECLARE c CURSOR FOR
|
||||
|
Reference in New Issue
Block a user