Re: Creating an index on a timestamp with time zone cast to a date-- possible?

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Wells Oliver <wells(dot)oliver(at)gmail(dot)com>
Cc: pgsql-admin <pgsql-admin(at)postgresql(dot)org>
Subject: Re: Creating an index on a timestamp with time zone cast to a date-- possible?
Date: 2021-05-24 18:24:47
Message-ID: 1012707.1621880687@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-admin

Wells Oliver <wells(dot)oliver(at)gmail(dot)com> writes:
> Seems you can't do this:
> create index on someschema.sometable ((modified_at::date));
> If modified_at is a timestamp with a time zone:
> ERROR: functions in index expression must be marked IMMUTABLE
> But you can if it's a timestamp without a time zone. Anyway, any way of
> casting that as to use it as an index?

The problem is that casting a timestamptz to a date (or a timestamp
for that matter) depends on your current timezone setting.

You could do something like

create index on sometable (((modified_at at time zone 'UTC')::date));

regards, tom lane

In response to

Browse pgsql-admin by date

  From Date Subject
Next Message Yambu 2021-05-25 04:37:42 bloat indicator using n_dead_tup column
Previous Message Wells Oliver 2021-05-24 18:19:05 Creating an index on a timestamp with time zone cast to a date-- possible?