From: | Thomas Kellerer <shammat(at)gmx(dot)net> |
---|---|
To: | pgsql-general(at)lists(dot)postgresql(dot)org |
Cc: | Snjezana Frketic <frketic(dot)snjezana(at)gmail(dot)com> |
Subject: | Re: How to select values in a JSON type of column? |
Date: | 2020-11-18 17:46:40 |
Message-ID: | ff765692-7c0c-c893-d033-37f4d33412fe@gmx.net |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-general |
Snjezana Frketic schrieb am 18.11.2020 um 17:00:
> I actually have version 9.3.17Ā š¬
>
>
> On Wed, 18 Nov 2020 at 15:55, Thomas Kellerer <shammat(at)gmx(dot)net <mailto:shammat(at)gmx(dot)net>> wrote:
>
> Snjezana Frketic schrieb am 18.11.2020 um 11:29:
> > I have a column calledĀ |targeting|Ā in a table calledĀ |campaigns|Ā .
> > [...]
> > and I need to select all theĀ |ids|Ā inĀ |includes|.
> > Currently, I am doing it like this
> >
> > SELECTĀ |targeting#>'{targets,0,audienceSegments,0,includes,0,segments,allOf,0,ids}'FROM campaigns;|
> >
>
> If you are on Postgres 12 or later, this can be done using jsonb_path_query_array:
>
> Ā select jsonb_path_query_array(targeting, '$.targets[*].*.includes.**.ids.id <http://ids.id>')
> Ā from campaigns
If you are limited to an unsupported version, you need to go down the hierarchy manually:
select t.ids
from campaigns c
cross join lateral (
select array_agg(s2.seg2 ->> 'id') as ids
from json_array_elements(c.targeting -> 'targets') as t(target)
cross join json_array_elements(t.target -> 'audienceSegments') as a(aud)
cross join json_array_elements(a.aud -> 'includes') as i(include)
cross join json_array_elements(i.include #> '{segments,allOf}') as s(seg)
cross join json_array_elements(s.seg -> 'ids') as s2(seg2)
) t
From | Date | Subject | |
---|---|---|---|
Next Message | Marcin Giedz | 2020-11-18 17:50:42 | Re: pg_upgrade from 12 to 13 failes with plpython2 |
Previous Message | Ron | 2020-11-18 17:15:03 | Re: psql backward compatibility |