]> granicus.if.org Git - postgresql/commitdiff
Repair recalculation failure for nested sub-SELECTs, per bug report from
authorTom Lane <tgl@sss.pgh.pa.us>
Tue, 11 May 2004 02:21:39 +0000 (02:21 +0000)
committerTom Lane <tgl@sss.pgh.pa.us>
Tue, 11 May 2004 02:21:39 +0000 (02:21 +0000)
Didier Moens.  Bug is new in 7.4, and was caused by not updating everyplace
I should've when replacing locParam markers by allParam.
Add a regression test to catch related errors in future.

src/backend/optimizer/plan/planner.c
src/test/regress/expected/subselect.out
src/test/regress/sql/subselect.sql

index c3cfe4be719719ba4ccd3dc2efdd0c639fd4e0c3..e094620d620afde730c6f054c17794cbf4211dd6 100644 (file)
@@ -8,7 +8,7 @@
  *
  *
  * IDENTIFICATION
- *       $PostgreSQL: pgsql/src/backend/optimizer/plan/planner.c,v 1.168 2004/04/07 18:17:24 tgl Exp $
+ *       $PostgreSQL: pgsql/src/backend/optimizer/plan/planner.c,v 1.169 2004/05/11 02:21:37 tgl Exp $
  *
  *-------------------------------------------------------------------------
  */
@@ -343,6 +343,9 @@ subquery_planner(Query *parse, double tuple_fraction)
 
                        plan->extParam = bms_add_members(plan->extParam,
                                                                                         initplan->plan->extParam);
+                       /* allParam must include all members of extParam */
+                       plan->allParam = bms_add_members(plan->allParam,
+                                                                                        plan->extParam);
                        initplan_cost += initplan->plan->total_cost;
                }
 
index f7b8297809f98101aa2856da0e49fd43456580a7..fb80fb0a503720aaf1f997335264f1af8b41a8a7 100644 (file)
@@ -201,3 +201,78 @@ select count(distinct ss.ten) from
     10
 (1 row)
 
+--
+-- Test case to catch problems with multiply nested sub-SELECTs not getting
+-- recalculated properly.  Per bug report from Didier Moens.
+--
+CREATE TABLE orderstest (
+    approver_ref integer,
+    po_ref integer,
+    ordercancelled boolean
+);
+INSERT INTO orderstest VALUES (1, 1, false);
+INSERT INTO orderstest VALUES (66, 5, false);
+INSERT INTO orderstest VALUES (66, 6, false);
+INSERT INTO orderstest VALUES (66, 7, false);
+INSERT INTO orderstest VALUES (66, 1, true);
+INSERT INTO orderstest VALUES (66, 8, false);
+INSERT INTO orderstest VALUES (66, 1, false);
+INSERT INTO orderstest VALUES (77, 1, false);
+INSERT INTO orderstest VALUES (1, 1, false);
+INSERT INTO orderstest VALUES (66, 1, false);
+INSERT INTO orderstest VALUES (1, 1, false);
+CREATE VIEW orders_view AS
+SELECT *,
+(SELECT CASE
+   WHEN ord.approver_ref=1 THEN '---' ELSE 'Approved'
+ END) AS "Approved",
+(SELECT CASE
+ WHEN ord.ordercancelled
+ THEN 'Cancelled'
+ ELSE
+  (SELECT CASE
+               WHEN ord.po_ref=1
+               THEN
+                (SELECT CASE
+                               WHEN ord.approver_ref=1
+                               THEN '---'
+                               ELSE 'Approved'
+                       END)
+               ELSE 'PO'
+       END) 
+END) AS "Status",
+(CASE
+ WHEN ord.ordercancelled
+ THEN 'Cancelled'
+ ELSE
+  (CASE
+               WHEN ord.po_ref=1
+               THEN
+                (CASE
+                               WHEN ord.approver_ref=1
+                               THEN '---'
+                               ELSE 'Approved'
+                       END)
+               ELSE 'PO'
+       END) 
+END) AS "Status_OK"
+FROM orderstest ord;
+SELECT * FROM orders_view;
+ approver_ref | po_ref | ordercancelled | Approved |  Status   | Status_OK 
+--------------+--------+----------------+----------+-----------+-----------
+            1 |      1 | f              | ---      | ---       | ---
+           66 |      5 | f              | Approved | PO        | PO
+           66 |      6 | f              | Approved | PO        | PO
+           66 |      7 | f              | Approved | PO        | PO
+           66 |      1 | t              | Approved | Cancelled | Cancelled
+           66 |      8 | f              | Approved | PO        | PO
+           66 |      1 | f              | Approved | Approved  | Approved
+           77 |      1 | f              | Approved | Approved  | Approved
+            1 |      1 | f              | ---      | ---       | ---
+           66 |      1 | f              | Approved | Approved  | Approved
+            1 |      1 | f              | ---      | ---       | ---
+(11 rows)
+
+DROP TABLE orderstest cascade;
+NOTICE:  drop cascades to rule _RETURN on view orders_view
+NOTICE:  drop cascades to view orders_view
index 5ff9d1cf875c44dc563a856e80e61a2b13980801..be3a0a87b5db7db78c8989f532e40c9d2377f346 100644 (file)
@@ -93,3 +93,67 @@ select count(*) from
 select count(distinct ss.ten) from
   (select ten from tenk1 a
    where unique1 IN (select distinct hundred from tenk1 b)) ss;
+
+--
+-- Test case to catch problems with multiply nested sub-SELECTs not getting
+-- recalculated properly.  Per bug report from Didier Moens.
+--
+
+CREATE TABLE orderstest (
+    approver_ref integer,
+    po_ref integer,
+    ordercancelled boolean
+);
+
+INSERT INTO orderstest VALUES (1, 1, false);
+INSERT INTO orderstest VALUES (66, 5, false);
+INSERT INTO orderstest VALUES (66, 6, false);
+INSERT INTO orderstest VALUES (66, 7, false);
+INSERT INTO orderstest VALUES (66, 1, true);
+INSERT INTO orderstest VALUES (66, 8, false);
+INSERT INTO orderstest VALUES (66, 1, false);
+INSERT INTO orderstest VALUES (77, 1, false);
+INSERT INTO orderstest VALUES (1, 1, false);
+INSERT INTO orderstest VALUES (66, 1, false);
+INSERT INTO orderstest VALUES (1, 1, false);
+
+CREATE VIEW orders_view AS
+SELECT *,
+(SELECT CASE
+   WHEN ord.approver_ref=1 THEN '---' ELSE 'Approved'
+ END) AS "Approved",
+(SELECT CASE
+ WHEN ord.ordercancelled
+ THEN 'Cancelled'
+ ELSE
+  (SELECT CASE
+               WHEN ord.po_ref=1
+               THEN
+                (SELECT CASE
+                               WHEN ord.approver_ref=1
+                               THEN '---'
+                               ELSE 'Approved'
+                       END)
+               ELSE 'PO'
+       END) 
+END) AS "Status",
+(CASE
+ WHEN ord.ordercancelled
+ THEN 'Cancelled'
+ ELSE
+  (CASE
+               WHEN ord.po_ref=1
+               THEN
+                (CASE
+                               WHEN ord.approver_ref=1
+                               THEN '---'
+                               ELSE 'Approved'
+                       END)
+               ELSE 'PO'
+       END) 
+END) AS "Status_OK"
+FROM orderstest ord;
+
+SELECT * FROM orders_view;
+
+DROP TABLE orderstest cascade;