Sorry,  I wrote the last sentence in a confusing way, I meant that I formed transformations for any number of "or" expressions (const_transform_or_limit=1). in regression tests, I noticed only diff changes of transformations of "or" expressions to "any". I attach a file with diff.

On 26.06.2023 04:47, Alena Rybakina wrote:

Hi, all! Sorry I haven't written for a long time.

I finished writing the code patch for transformation "Or" expressions to "Any" expressions. I didn't see any problems in regression tests, even when I changed the constant at which the minimum or expression is replaced by any at 0. I ran my patch on sqlancer and so far the code has never fallen.

On 14.01.2023 18:45, Marcos Pegoraro wrote:

    I agree with your idea and try to implement it and will soon
    attach a patch with a solution.

Additionally, if those OR constants repeat you'll see ...
If all constants are the same value, fine
explain select * from x where ((ID = 1) OR (ID = 1) OR (ID = 1));
Index Only Scan using x_id on x  (cost=0.42..4.44 rows=1 width=4)
  Index Cond: (id = 1)

if all values are almost the same, ops
explain select * from x where ((ID = 1) OR (ID = 1) OR (ID = 1) OR (ID = 2));
Bitmap Heap Scan on x  (cost=17.73..33.45 rows=4 width=4)
  Recheck Cond: ((id = 1) OR (id = 1) OR (id = 1) OR (id = 2))
  ->  BitmapOr  (cost=17.73..17.73 rows=4 width=0)
        ->  Bitmap Index Scan on x_id  (cost=0.00..4.43 rows=1 width=0)
              Index Cond: (id = 1)
        ->  Bitmap Index Scan on x_id  (cost=0.00..4.43 rows=1 width=0)
              Index Cond: (id = 1)
        ->  Bitmap Index Scan on x_id  (cost=0.00..4.43 rows=1 width=0)
              Index Cond: (id = 1)
        ->  Bitmap Index Scan on x_id  (cost=0.00..4.43 rows=1 width=0)
              Index Cond: (id = 2)

thanks
Marcos

--

Regards,

Alena Rybakina
diff -U3 /home/alena/postgrespro9/src/test/regress/expected/create_index.out 
/home/alena/postgrespro9/src/test/regress/results/create_index.out
--- /home/alena/postgrespro9/src/test/regress/expected/create_index.out 
2023-06-26 04:08:22.903294342 +0300
+++ /home/alena/postgrespro9/src/test/regress/results/create_index.out  
2023-06-26 05:36:31.904205986 +0300
@@ -1838,18 +1838,11 @@
 EXPLAIN (COSTS OFF)
 SELECT * FROM tenk1
   WHERE thousand = 42 AND (tenthous = 1 OR tenthous = 3 OR tenthous = 42);
-                                                               QUERY PLAN      
                                                          
------------------------------------------------------------------------------------------------------------------------------------------
- Bitmap Heap Scan on tenk1
-   Recheck Cond: (((thousand = 42) AND (tenthous = 1)) OR ((thousand = 42) AND 
(tenthous = 3)) OR ((thousand = 42) AND (tenthous = 42)))
-   ->  BitmapOr
-         ->  Bitmap Index Scan on tenk1_thous_tenthous
-               Index Cond: ((thousand = 42) AND (tenthous = 1))
-         ->  Bitmap Index Scan on tenk1_thous_tenthous
-               Index Cond: ((thousand = 42) AND (tenthous = 3))
-         ->  Bitmap Index Scan on tenk1_thous_tenthous
-               Index Cond: ((thousand = 42) AND (tenthous = 42))
-(9 rows)
+                                  QUERY PLAN                                  
+------------------------------------------------------------------------------
+ Index Scan using tenk1_thous_tenthous on tenk1
+   Index Cond: ((thousand = 42) AND (tenthous = ANY ('{1,3,42}'::integer[])))
+(2 rows)
 
 SELECT * FROM tenk1
   WHERE thousand = 42 AND (tenthous = 1 OR tenthous = 3 OR tenthous = 42);
@@ -1861,20 +1854,17 @@
 EXPLAIN (COSTS OFF)
 SELECT count(*) FROM tenk1
   WHERE hundred = 42 AND (thousand = 42 OR thousand = 99);
-                                   QUERY PLAN                                  
  
----------------------------------------------------------------------------------
+                                     QUERY PLAN                                
     
+------------------------------------------------------------------------------------
  Aggregate
    ->  Bitmap Heap Scan on tenk1
-         Recheck Cond: ((hundred = 42) AND ((thousand = 42) OR (thousand = 
99)))
+         Recheck Cond: ((hundred = 42) AND (thousand = ANY 
('{42,99}'::integer[])))
          ->  BitmapAnd
                ->  Bitmap Index Scan on tenk1_hundred
                      Index Cond: (hundred = 42)
-               ->  BitmapOr
-                     ->  Bitmap Index Scan on tenk1_thous_tenthous
-                           Index Cond: (thousand = 42)
-                     ->  Bitmap Index Scan on tenk1_thous_tenthous
-                           Index Cond: (thousand = 99)
-(11 rows)
+               ->  Bitmap Index Scan on tenk1_thous_tenthous
+                     Index Cond: (thousand = ANY ('{42,99}'::integer[]))
+(8 rows)
 
 SELECT count(*) FROM tenk1
   WHERE hundred = 42 AND (thousand = 42 OR thousand = 99);
diff -U3 /home/alena/postgrespro9/src/test/regress/expected/join.out 
/home/alena/postgrespro9/src/test/regress/results/join.out
--- /home/alena/postgrespro9/src/test/regress/expected/join.out 2023-06-26 
04:08:22.903294342 +0300
+++ /home/alena/postgrespro9/src/test/regress/results/join.out  2023-06-26 
05:36:36.748191699 +0300
@@ -4184,10 +4184,10 @@
 select * from tenk1 a join tenk1 b on
   (a.unique1 = 1 and b.unique1 = 2) or
   ((a.unique2 = 3 or a.unique2 = 7) and b.hundred = 4);
-                                                      QUERY PLAN               
                                       
-----------------------------------------------------------------------------------------------------------------------
+                                                       QUERY PLAN              
                                         
+------------------------------------------------------------------------------------------------------------------------
  Nested Loop
-   Join Filter: (((a.unique1 = 1) AND (b.unique1 = 2)) OR (((a.unique2 = 3) OR 
(a.unique2 = 7)) AND (b.hundred = 4)))
+   Join Filter: (((a.unique1 = 1) AND (b.unique1 = 2)) OR ((a.unique2 = ANY 
('{3,7}'::integer[])) AND (b.hundred = 4)))
    ->  Bitmap Heap Scan on tenk1 b
          Recheck Cond: ((unique1 = 2) OR (hundred = 4))
          ->  BitmapOr
@@ -4197,15 +4197,13 @@
                      Index Cond: (hundred = 4)
    ->  Materialize
          ->  Bitmap Heap Scan on tenk1 a
-               Recheck Cond: ((unique1 = 1) OR (unique2 = 3) OR (unique2 = 7))
+               Recheck Cond: ((unique1 = 1) OR (unique2 = ANY 
('{3,7}'::integer[])))
                ->  BitmapOr
                      ->  Bitmap Index Scan on tenk1_unique1
                            Index Cond: (unique1 = 1)
                      ->  Bitmap Index Scan on tenk1_unique2
-                           Index Cond: (unique2 = 3)
-                     ->  Bitmap Index Scan on tenk1_unique2
-                           Index Cond: (unique2 = 7)
-(19 rows)
+                           Index Cond: (unique2 = ANY ('{3,7}'::integer[]))
+(17 rows)
 
 --
 -- test placement of movable quals in a parameterized join tree
diff -U3 /home/alena/postgrespro9/src/test/regress/expected/stats_ext.out 
/home/alena/postgrespro9/src/test/regress/results/stats_ext.out
--- /home/alena/postgrespro9/src/test/regress/expected/stats_ext.out    
2023-06-26 04:04:26.560435094 +0300
+++ /home/alena/postgrespro9/src/test/regress/results/stats_ext.out     
2023-06-26 05:36:48.300155667 +0300
@@ -1322,19 +1322,19 @@
 SELECT * FROM check_estimated_rows('SELECT * FROM functional_dependencies 
WHERE (a = 1 OR a = 51) AND b = ''1''');
  estimated | actual 
 -----------+--------
-        99 |    100
+       100 |    100
 (1 row)
 
 SELECT * FROM check_estimated_rows('SELECT * FROM functional_dependencies 
WHERE (a = 1 OR a = 51) AND (b = ''1'' OR b = ''2'')');
  estimated | actual 
 -----------+--------
-        99 |    100
+       100 |    100
 (1 row)
 
 SELECT * FROM check_estimated_rows('SELECT * FROM functional_dependencies 
WHERE (a = 1 OR a = 2 OR a = 51 OR a = 52) AND (b = ''1'' OR b = ''2'')');
  estimated | actual 
 -----------+--------
-       197 |    200
+       200 |    200
 (1 row)
 
 -- OR clauses referencing different attributes are incompatible
@@ -1664,19 +1664,19 @@
 SELECT * FROM check_estimated_rows('SELECT * FROM functional_dependencies 
WHERE ((a * 2) = 2 OR (a * 2) = 102) AND upper(b) = ''1''');
  estimated | actual 
 -----------+--------
-        99 |    100
+       100 |    100
 (1 row)
 
 SELECT * FROM check_estimated_rows('SELECT * FROM functional_dependencies 
WHERE ((a * 2) = 2 OR (a * 2) = 102) AND (upper(b) = ''1'' OR upper(b) = 
''2'')');
  estimated | actual 
 -----------+--------
-        99 |    100
+       100 |    100
 (1 row)
 
 SELECT * FROM check_estimated_rows('SELECT * FROM functional_dependencies 
WHERE ((a * 2) = 2 OR (a * 2) = 4 OR (a * 2) = 102 OR (a * 2) = 104) AND 
(upper(b) = ''1'' OR upper(b) = ''2'')');
  estimated | actual 
 -----------+--------
-       197 |    200
+       200 |    200
 (1 row)
 
 -- OR clauses referencing different attributes
diff -U3 /home/alena/postgrespro9/src/test/regress/expected/partition_prune.out 
/home/alena/postgrespro9/src/test/regress/results/partition_prune.out
--- /home/alena/postgrespro9/src/test/regress/expected/partition_prune.out      
2023-06-26 04:05:30.305209590 +0300
+++ /home/alena/postgrespro9/src/test/regress/results/partition_prune.out       
2023-06-26 05:36:58.912120163 +0300
@@ -82,23 +82,23 @@
 (2 rows)
 
 explain (costs off) select * from lp where a = 'a' or a = 'c';
-                        QUERY PLAN                        
-----------------------------------------------------------
+                  QUERY PLAN                   
+-----------------------------------------------
  Append
    ->  Seq Scan on lp_ad lp_1
-         Filter: ((a = 'a'::bpchar) OR (a = 'c'::bpchar))
+         Filter: (a = ANY ('{a,c}'::bpchar[]))
    ->  Seq Scan on lp_bc lp_2
-         Filter: ((a = 'a'::bpchar) OR (a = 'c'::bpchar))
+         Filter: (a = ANY ('{a,c}'::bpchar[]))
 (5 rows)
 
 explain (costs off) select * from lp where a is not null and (a = 'a' or a = 
'c');
-                                   QUERY PLAN                                  
 
---------------------------------------------------------------------------------
+                             QUERY PLAN                              
+---------------------------------------------------------------------
  Append
    ->  Seq Scan on lp_ad lp_1
-         Filter: ((a IS NOT NULL) AND ((a = 'a'::bpchar) OR (a = 'c'::bpchar)))
+         Filter: ((a IS NOT NULL) AND (a = ANY ('{a,c}'::bpchar[])))
    ->  Seq Scan on lp_bc lp_2
-         Filter: ((a IS NOT NULL) AND ((a = 'a'::bpchar) OR (a = 'c'::bpchar)))
+         Filter: ((a IS NOT NULL) AND (a = ANY ('{a,c}'::bpchar[])))
 (5 rows)
 
 explain (costs off) select * from lp where a <> 'g';
@@ -515,10 +515,10 @@
 (27 rows)
 
 explain (costs off) select * from rlp where a = 1 or a = 7;
-           QUERY PLAN           
---------------------------------
+                QUERY PLAN                
+------------------------------------------
  Seq Scan on rlp2 rlp
-   Filter: ((a = 1) OR (a = 7))
+   Filter: (a = ANY ('{1,7}'::integer[]))
 (2 rows)
 
 explain (costs off) select * from rlp where a = 1 or b = 'ab';
@@ -596,13 +596,13 @@
 
 -- where clause contradicts sub-partition's constraint
 explain (costs off) select * from rlp where a = 20 or a = 40;
-               QUERY PLAN               
-----------------------------------------
+                    QUERY PLAN                    
+--------------------------------------------------
  Append
    ->  Seq Scan on rlp4_1 rlp_1
-         Filter: ((a = 20) OR (a = 40))
+         Filter: (a = ANY ('{20,40}'::integer[]))
    ->  Seq Scan on rlp5_default rlp_2
-         Filter: ((a = 20) OR (a = 40))
+         Filter: (a = ANY ('{20,40}'::integer[]))
 (5 rows)
 
 explain (costs off) select * from rlp3 where a = 20;   /* empty */
@@ -1933,10 +1933,10 @@
 
 explain (costs off) select * from hp where a = 1 and b = 'abcde' and
   (c = 2 or c = 3);
-                              QUERY PLAN                              
-----------------------------------------------------------------------
+                                   QUERY PLAN                                  
 
+--------------------------------------------------------------------------------
  Seq Scan on hp2 hp
-   Filter: ((a = 1) AND (b = 'abcde'::text) AND ((c = 2) OR (c = 3)))
+   Filter: ((c = ANY ('{2,3}'::integer[])) AND (a = 1) AND (b = 'abcde'::text))
 (2 rows)
 
 drop table hp2;
@@ -2265,11 +2265,11 @@
          Workers Launched: N
          ->  Parallel Append (actual rows=N loops=N)
                ->  Parallel Seq Scan on ab_a1_b2 ab_1 (actual rows=N loops=N)
-                     Filter: ((b = 2) AND ((a = $0) OR (a = $1)))
+                     Filter: ((a = ANY (ARRAY[$0, $1])) AND (b = 2))
                ->  Parallel Seq Scan on ab_a2_b2 ab_2 (never executed)
-                     Filter: ((b = 2) AND ((a = $0) OR (a = $1)))
+                     Filter: ((a = ANY (ARRAY[$0, $1])) AND (b = 2))
                ->  Parallel Seq Scan on ab_a3_b2 ab_3 (actual rows=N loops=N)
-                     Filter: ((b = 2) AND ((a = $0) OR (a = $1)))
+                     Filter: ((a = ANY (ARRAY[$0, $1])) AND (b = 2))
 (16 rows)
 
 -- Test pruning during parallel nested loop query

Reply via email to