Re: How to update upper-bound of tstzrange ? - Mailing list pgsql-general

From Laurenz Albe
Subject Re: How to update upper-bound of tstzrange ?
Date
Msg-id 82f02004dc5fd734c925d4db0c48190e8100a42d.camel@cybertec.at
Whole thread Raw
In response to Re: How to update upper-bound of tstzrange ?  (Erik Wienhold <ewie@ewie.name>)
Responses Re: How to update upper-bound of tstzrange ?
List pgsql-general
On Mon, 2024-05-20 at 13:56 +0200, Erik Wienhold wrote:
> On 2024-05-20 12:30 +0200, Laura Smith wrote:
> > Could someone kindly help me out with the correct syntax ?
> >
> > My first thought was the below but that doesn't work:
> >
> > update foo set upper(bar_times)=upper(bar_times)+interval '1' hour where bar_id='abc';
> > ERROR:  syntax error at or near "("
> > LINE 1: update event_sessions set upper(bar_times)=upper(bar_ti...
>
> Use the constructor function:
>
>     UPDATE foo SET bar_times = tstzrange(lower(bar_times), upper(bar_times) + interval '1' hour);
>
> But this does not preserve the inclusivity/exclusivity of bounds from
> the input range, so you may have to pass in the third argument as well.
>
> https://www.postgresql.org/docs/current/rangetypes.html#RANGETYPES-CONSTRUCT

If you need to preserve the information whether the upper and lower bounds
are inclusive or not, you could

  UPDATE foo
  SET bar_times = tstzrange(
                     lower(bar_times),
                     upper (bar_times) + INTERVAL '1 hour',
                     CASE WHEN lower_inc(bar_times) THEN '[' ELSE '(' END ||
                     CASE WHEN upper_inc(bar_times) THEN ']' ELSE ')' END
                  )
  WHERE ...

Yours,
Laurenz Albe



pgsql-general by date:

Previous
From: Ron Johnson
Date:
Subject: Re: pg_dump and not MVCC-safe commands
Next
From: Laurenz Albe
Date:
Subject: Re: problem with query