Re: JSON and Postgres Variable Queries

From: Andrew Dunstan <andrew(at)dunslane(dot)net>
To: Robert Haas <robertmhaas(at)gmail(dot)com>
Cc: Joey Caughey <jcaughey(at)parrotmarketing(dot)com>, "pgsql-hackers(at)postgresql(dot)org" <pgsql-hackers(at)postgresql(dot)org>, gkimball(at)parrotmarketing(dot)com
Subject: Re: JSON and Postgres Variable Queries
Date: 2014-06-23 15:32:41
Message-ID: 53A84899.6080102@dunslane.net
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-hackers


On 06/23/2014 11:06 AM, Robert Haas wrote:
> On Fri, Jun 20, 2014 at 11:26 AM, Joey Caughey
> <jcaughey(at)parrotmarketing(dot)com> wrote:
>> I’m having an issue with JSON requests in Postgres and was wondering if
>> anyone had an answer.
>>
>> I have an orders table with a field called “json_data”.
>>
>> In the json data there is a plan’s array with an id value in them.
>> { "plan”: { “id”: “1” } } }
>>
>> I can do regular queries that will work, like so:
>> SELECT json_data->>’plan'->>’id' as plan_id FROM orders;
>>
>> But if I try to query on the data that is returned it will fail:
>> SELECT json_data->>’plan'->>’id' as plan_id FROM orders WHERE plan_id = 1;
>> OR
>> SELECT json_data->>’plan'->>’id' as plan_id FROM orders GROUP BY plan_id;
>> OR
>> SELECT json_data->>’plan'->>’id' as plan_id FROM orders ORDER BY plan_id;
>>
>> Is this something that has been overlooked? or is there another way to go
>> about this?
> You might find a sub-SELECT helpful:
>
> SELECT * FROM (SELECT json_data->>’plan'->>’id' as plan_id FROM
> orders) x WHERE plan_id = 1
>
> It might be a generally useful thing for WHERE-clause items to be able
> to reference items from the target list by alias, or maybe it's
> problematic for some reason that I don't know about, but right now
> they can't.
>

Once again,

json_data->>’plan'->>’id'

is an expression guaranteed to fail, since ->> returns text but expects
its left hand o0perand to be json, unlike

json_data->’plan'->>’id'

or

json_data#>>'{plan,id}'

So I don't believe the OPs original statement about what is and isn't
working. The alias issue, of course, is not at all JSON-specific, and
the subselect is one solution - a CTE is another. But you CAN use the
alias in an ORDER BY or GROUP BY.

cheers

andrew

In response to

Browse pgsql-hackers by date

  From Date Subject
Next Message Andres Freund 2014-06-23 15:42:28 Re: Wait free LW_SHARED acquisition - v0.2
Previous Message Andres Freund 2014-06-23 15:28:32 Re: replication identifier format