Search Postgresql Archives

Re: ERROR: functions in index expression must be marked IMMUTABLE

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

 



On 02/28/2017 01:35 AM, Sven R. Kunze wrote:
On 27.02.2017 18:17, Adrian Klaver wrote:
Yes, but is not about timezone dependency, it is about the other
dependencies listed in the second and third points. Namely the
datestyle setting and magic strings e.g. 'now'

I am sorry, I still don't understand. to_date and to_timestamp require
datestyle settings per se and magic strings don't work.

See here:

https://www.postgresql.org/message-id/11190.1488127834%40sss.pgh.pa.us

"There are multiple reasons why the text-to-datetime conversion functions are not immutable"

Tom was referring to the text --> date cast you where attempting in your original index definition:

create index docs_birthdate_idx ON docs using btree
(((meta->>'birthdate')::date));

So:

test=> select 'today'::date;
    date
------------
 2017-02-28
(1 row)

test=> select 'now'::date;
    date
------------
 2017-02-28
(1 row)

test=> set datestyle = 'SQL, DMY';
SET
test=> select 'today'::date;
    date
------------
 28/02/2017
(1 row)

test=> select 'now'::date;
    date
------------
 28/02/2017
(1 row)


Now you tried to work around the casting issue by using to_timestamp:

create index docs_birthdate_idx ON docs using btree
((to_timestamp(meta->>'birthdate', 'YYYY-MM-DD') at time zone 'UTC'));

but that introduced the issue that to_timestamp returns a timestamptz and so you end up with a dependency on timezones.



=# -- required datestyle
=# select to_date('2000-01-01');
ERROR:  function to_date(unknown) does not exist
LINE 1: select to_date('2000-01-01');
               ^
HINT:  No function matches the given name and argument types. You might
need to add explicit type casts.


=# -- magic strings don't work
=# select to_date('');
ERROR:  invalid value "epoc" for "YYYY"
DETAIL:  Value must be an integer.
=# select to_date('epoch', 'YYYY-MM-DD');
ERROR:  invalid value "epoc" for "YYYY"
DETAIL:  Value must be an integer.
=# select to_date('infinity', 'YYYY-MM-DD');
ERROR:  invalid value "infi" for "YYYY"
DETAIL:  Value must be an integer.
=# select to_date('-infinity', 'YYYY-MM-DD');
ERROR:  invalid value "-inf" for "YYYY"
DETAIL:  Value must be an integer.
=# select to_date('now', 'YYYY-MM-DD');
ERROR:  invalid value "now" for "YYYY"
DETAIL:  Value must be an integer.
=# select to_date('today', 'YYYY-MM-DD');
ERROR:  invalid value "toda" for "YYYY"
DETAIL:  Value must be an integer.
=# select to_date('tomorrow', 'YYYY-MM-DD');
ERROR:  invalid value "tomo" for "YYYY"
DETAIL:  Value must be an integer.
=# select to_date('yesterday', 'YYYY-MM-DD');
ERROR:  invalid value "yest" for "YYYY"
DETAIL:  Value must be an integer.
=# select to_date('allballs', 'YYYY-MM-DD');
ERROR:  invalid value "allb" for "YYYY"
DETAIL:  Value must be an integer.

Regards,
Sven


--
Adrian Klaver
adrian.klaver@xxxxxxxxxxx


--
Sent via pgsql-general mailing list (pgsql-general@xxxxxxxxxxxxxx)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general



[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 Books]     [PHP Databases]     [Postgresql & PHP]     [Yosemite]
  Powered by Linux