Search Postgresql Archives

Re: Strange behaviors with ranges

[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]

 



On 8/27/24 10:29, Jean-Christophe Boggio wrote:
I have 2 very confusing behaviors when using ranges.

It all started with this query:

     WITH rangespaliers AS (
        SELECT numrange( qtep1+1   , qtep2,  '[]') AS rangep FROM paliers JOIN tmp_limitcontrats USING(idcontrat)
--        SELECT numrange( qtep1+1   , qtep2,  '[]') AS rangep FROM paliers WHERE idcontrat=1003
     )
     ,rangespaliers2 AS (
         select *
         FROM rangespaliers
         WHERE rangep <> NUMRANGE(NULL, NULL) -- ERROR IS HERE
     )
     select * from rangespaliers2;

When I run this query, I get the error "Range lower bound must be less than or equal to range upper bound".

(a) If I comment out the line marked "ERROR IS HERE", I don't have an error (but I'm missing the filter of course).

(b) Also, if I uncomment line 3 and comment out line 2, I get the correct behavior. Very strange thing is that tmp_limitcontrats has only one row which contains "idcontrat=1003".

The issue is the order-of-operations used by the planner. If I put EXPLAIN on your last query, I see:

 Hash Join  (cost=16.64..109.90 rows=2410 width=64)
   Hash Cond: (tmp_limitcontrats.idcontrat = paliers.idcontrat)
   ->  Seq Scan on tmp_limitcontrats  (cost=0.00..35.50 rows=2550 width=4)
   ->  Hash  (cost=14.27..14.27 rows=189 width=12)
         ->  Seq Scan on paliers  (cost=0.00..14.27 rows=189 width=12)
               Filter: (numrange(((qtep1 + 1))::numeric, (qtep2)::numeric) <> '(,)'::numrange)

So we are applying that filter to every row in paliers, not just the one with idcontrat = 1003.

Indeed this simplified version also fails:

SELECT numrange(qtep1+1,qtep2) as rangep FROM paliers;

Yours,

--
Paul              ~{:-)
pj@xxxxxxxxxxxxxxxxxxxxxxxx





[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]
[Index of Archives]     [Postgresql Jobs]     [Postgresql Admin]     [Postgresql Performance]     [Linux Clusters]     [PHP Home]     [PHP on Windows]     [Kernel Newbies]     [PHP Classes]     [PHP Databases]     [Postgresql & PHP]     [Yosemite]

  Powered by Linux