From: | Larry Rosenman <ler(at)lerctr(dot)org> |
---|---|
To: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
Cc: | pgsql-sql(at)postgresql(dot)org |
Subject: | Re: create index on a jsonb timestamp field? |
Date: | 2019-05-19 19:37:55 |
Message-ID: | 8b5563be3bf7f0ae9826b223b61fa22d@lerctr.org |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-sql |
On 05/18/2019 8:17 pm, Tom Lane wrote:
> Larry Rosenman <ler(at)lerctr(dot)org> writes:
>> when I try to create an index on the query_time field of the json
>> structure I get:
>> ler=# create index dns_query_time_idx on dns_query(((data -> 'message'
>> ->> 'query_time')::text::timestamptz));
>> ERROR: functions in index expression must be marked IMMUTABLE
>
> Yeah, because the timestamptz input function has dependencies on
> both the datestyle and timezone GUCs. Given that your input is
> ISO-format with explicit time zone, you don't really care about
> either of those things, but the mutability check doesn't know that.
>
>> Is there any easy way to do this? Or, what would the experts
>> recommend
>> here?
>
> The sanest way to deal with this IMO is to make a column containing
> the extracted timestamp, which you could maintain with a trigger,
> and then index that. You could alternatively make a custom function
> that you (mis?)label as immutable, but your queries would have to
> use that same function in order to get matched to the index, so
> I dunno about that being a user-friendly approach.
This is what I wound up figuring out between my original post and yours,
and it works great.
>
> BTW, I'd had the idea that the GENERATED option in PG v13 would allow
> setting up this sort of case without bothering with a handwritten
> trigger,
> but it seems not:
>
> regression=# create table foo(data jsonb, ts timestamptz GENERATED
> ALWAYS AS ((data->>'ts')::timestamptz) stored);
> psql: ERROR: generation expression is not immutable
>
> I wonder if that's really necessary to insist on?
Good question. Is that something the project is going to look into?
>
> regards, tom lane
--
Larry Rosenman http://www.lerctr.org/~ler
Phone: +1 214-642-9640 E-Mail: ler(at)lerctr(dot)org
US Mail: 5708 Sabbia Dr, Round Rock, TX 78665-2106
From | Date | Subject | |
---|---|---|---|
Next Message | Tom Lane | 2019-05-19 19:55:54 | Re: create index on a jsonb timestamp field? |
Previous Message | Pavel Stehule | 2019-05-19 16:20:29 | Re: Table as argument in postgres function |