Thread: Re: Strange behaviors with ranges

Re: Strange behaviors with ranges

From
Adrian Klaver
Date:

On 8/27/24 10:29 AM, Jean-Christophe Boggio wrote:
> Hello,
> 
> 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".

What does:

SELECT numrange( qtep1+1   , qtep2,  '[]') AS rangep FROM paliers WHERE 
idcontrat=1003

return?


> 
> This fails on PG 16.4 and 15.7
> 
> Thanks a lot for your enlightenment.
> 

-- 
Adrian Klaver
adrian.klaver@aklaver.com



Re: Strange behaviors with ranges

From
Jean-Christophe Boggio
Date:
> What does:
>
> SELECT numrange( qtep1+1   , qtep2,  '[]') AS rangep FROM paliers 
> WHERE idcontrat=1003
>
> return?

It returns:

(,)

(as expected)





Re: Strange behaviors with ranges

From
Torsten Förtsch
Date:
I guess this query comes back non-empty:

SELECT * FROM paliers JOIN tmp_limitcontrats USING(idcontrat) WHERE qtep1 >= qtep2

This would then lead somewhere to this expression numrange(3,2)

Check out idpalier=805


On Tue, Aug 27, 2024 at 7:37 PM Adrian Klaver <adrian.klaver@aklaver.com> wrote:


On 8/27/24 10:29 AM, Jean-Christophe Boggio wrote:
> Hello,
>
> 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".

What does:

SELECT numrange( qtep1+1   , qtep2,  '[]') AS rangep FROM paliers WHERE
idcontrat=1003

return?


>
> This fails on PG 16.4 and 15.7
>
> Thanks a lot for your enlightenment.
>

--
Adrian Klaver
adrian.klaver@aklaver.com


Re: Strange behaviors with ranges

From
Jean-Christophe BOGGIO
Date:
Le 27/08/2024 à 19:51, Torsten Förtsch a écrit :
I guess this query comes back non-empty:

SELECT * FROM paliers JOIN tmp_limitcontrats USING(idcontrat) WHERE qtep1 >= qtep2

Yes, it is empty if I keep tmp_limitcontrats to idcontrat=1003

Otherwise, you are right, there are irregular data but not that I'm concerned with in that particular case.


Re: Strange behaviors with ranges

From
Adrian Klaver
Date:

On 8/27/24 11:13 AM, Jean-Christophe BOGGIO wrote:
> Le 27/08/2024 à 19:51, Torsten Förtsch a écrit :
>> I guess this query comes back non-empty:
>>
>> SELECT * FROM paliers JOIN tmp_limitcontrats USING(idcontrat) WHERE 
>> qtep1 >= qtep2
> 
> Yes, it is empty if I keep tmp_limitcontrats to idcontrat=1003
> 
> Otherwise, you are right, there are irregular data but not that I'm 
> concerned with in that particular case.
> 

?:
SELECT numrange( qtep1+1   , qtep2,  '[]') AS rangep FROM paliers JOIN 
tmp_limitcontrats USING(idcontrat) where qtep1+1 < qtep2

-- 
Adrian Klaver
adrian.klaver@aklaver.com



Re: Strange behaviors with ranges

From
Adrian Klaver
Date:

On 8/27/24 11:16 AM, Adrian Klaver wrote:
> 
> 
> On 8/27/24 11:13 AM, Jean-Christophe BOGGIO wrote:
>> Le 27/08/2024 à 19:51, Torsten Förtsch a écrit :
>>> I guess this query comes back non-empty:
>>>
>>> SELECT * FROM paliers JOIN tmp_limitcontrats USING(idcontrat) WHERE 
>>> qtep1 >= qtep2
>>
>> Yes, it is empty if I keep tmp_limitcontrats to idcontrat=1003
>>
>> Otherwise, you are right, there are irregular data but not that I'm 
>> concerned with in that particular case.
>>
> 
> ?:
> SELECT numrange( qtep1+1   , qtep2,  '[]') AS rangep FROM paliers JOIN 
> tmp_limitcontrats USING(idcontrat) where qtep1+1 < qtep2
> 

Actually that should be:

qtep1+1 <= qtep2

-- 
Adrian Klaver
adrian.klaver@aklaver.com