Thread: querying within json
<div dir="ltr">Any advice on how to best query for values within json (using 9.4). I have numeric fields within the jsonand want to include terms for those fields.<br /><br /> I've found that something like this works:<br /><br /> select* from atable where (json_col->>'numeric_prop')::numeric < 100;<br /><br /> But whilst that works:<br /> 1.seems to have unnecessary casts? The numeric _prop item is of numeric type, but its getting retrieved as text and thencast to numeric and then compared<br /> 2. its not going to use any index on the json_col jsonb column.<br /><br /> Isthere a better way to do this?<br /><br /><br /> Thanks<br /> Tim<br /></div>
Hi Tim,
2014-10-30 15:55 GMT+01:00 Tim Dudgeon <tdudgeon.ml@gmail.com>:
-- Any advice on how to best query for values within json (using 9.4). I have numeric fields within the json and want to include terms for those fields.
I've found that something like this works:
select * from atable where (json_col->>'numeric_prop')::numeric < 100;
But whilst that works:
1. seems to have unnecessary casts? The numeric _prop item is of numeric type, but its getting retrieved as text and then cast to numeric and then compared
The right operand type of the ->> oeprator is text when ->> is used to get a json object field. So the cast to numeric is needed.
2. its not going to use any index on the json_col jsonb column.
The usage of an index is mostly ruled by the 'selectivity' of the query. Anyway, if querying for particular items within the key is common (as 'numeric_prop' in your example), defining an index like this may be worthwhile:
CREATE INDEX idxgin_numeric_prop ON atable USING gin((json_col->'numeric_prop'));
Regards,
Giuseppe Broccolo - 2ndQuadrant Italy
PostgreSQL Training, Services and Support
giuseppe.broccolo@2ndQuadrant.it | www.2ndQuadrant.it
PostgreSQL Training, Services and Support
giuseppe.broccolo@2ndQuadrant.it | www.2ndQuadrant.it
On 30/10/2014 15:22, Giuseppe Broccolo wrote:
Needed to work, yes. But if my reading of the docs is right then numeric types within json as supposed to be treated as Postgres numeric type?
See table 8.23 here: http://www.postgresql.org/docs/9.4/static/datatype-json.html
So this would mean a cast from numeric to text and then back to numeric?
There is no way to ask for a json 'field' in its actual data type so avoiding the cast?
I can add the index, but no evidence of it being used when I run a query like this:
select * from atable where (json_col->>'numeric_prop')::numeric < 100;
Tim
Hi Tim,2014-10-30 15:55 GMT+01:00 Tim Dudgeon <tdudgeon.ml@gmail.com>:Any advice on how to best query for values within json (using 9.4). I have numeric fields within the json and want to include terms for those fields.
I've found that something like this works:
select * from atable where (json_col->>'numeric_prop')::numeric < 100;
But whilst that works:
1. seems to have unnecessary casts? The numeric _prop item is of numeric type, but its getting retrieved as text and then cast to numeric and then comparedThe right operand type of the ->> oeprator is text when ->> is used to get a json object field. So the cast to numeric is needed.
Needed to work, yes. But if my reading of the docs is right then numeric types within json as supposed to be treated as Postgres numeric type?
See table 8.23 here: http://www.postgresql.org/docs/9.4/static/datatype-json.html
So this would mean a cast from numeric to text and then back to numeric?
There is no way to ask for a json 'field' in its actual data type so avoiding the cast?
2. its not going to use any index on the json_col jsonb column.The usage of an index is mostly ruled by the 'selectivity' of the query. Anyway, if querying for particular items within the key is common (as 'numeric_prop' in your example), defining an index like this may be worthwhile:CREATE INDEX idxgin_numeric_prop ON atable USING gin((json_col->'numeric_prop'));
I can add the index, but no evidence of it being used when I run a query like this:
select * from atable where (json_col->>'numeric_prop')::numeric < 100;
Tim
--Regards,Giuseppe Broccolo - 2ndQuadrant Italy
PostgreSQL Training, Services and Support
giuseppe.broccolo@2ndQuadrant.it | www.2ndQuadrant.it
Tim Dudgeon wrote > On 30/10/2014 15:22, Giuseppe Broccolo wrote: >> Hi Tim, >> >> 2014-10-30 15:55 GMT+01:00 Tim Dudgeon < > tdudgeon.ml@ > > > <mailto: > tdudgeon.ml@ > >>: >> >> Any advice on how to best query for values within json (using >> 9.4). I have numeric fields within the json and want to include >> terms for those fields. >> >> I've found that something like this works: >> >> select * from atable where (json_col->>'numeric_prop')::numeric < >> 100; >> >> But whilst that works: >> 1. seems to have unnecessary casts? The numeric _prop item is of >> numeric type, but its getting retrieved as text and then cast to >> numeric and then compared >> >> >> The right operand type of the ->> oeprator is text when ->> is used to >> get a json object field. So the cast to numeric is needed. > > Needed to work, yes. But if my reading of the docs is right then numeric > types within json as supposed to be treated as Postgres numeric type? > See table 8.23 here: > http://www.postgresql.org/docs/9.4/static/datatype-json.html > So this would mean a cast from numeric to text and then back to numeric? > There is no way to ask for a json 'field' in its actual data type so > avoiding the cast? While the semantic definition of json-number and postgres-numeric are made to be similar (allowed range of values mostly, plus when creating json from a numeric the system knows to store the data as a number instead of as text) there is currently no way to directly go from the internal json-number representation to postgres-numeric. On a technical side-note: "The right operand type of the ->> oeprator [sic] is text when ->> is used to get a json object field. So the cast to numeric is needed." doesn't make sense. The fact that the right operand is text has no bearing on whether a cast to numeric is required. The fact that the operator "json->>text" returns text does. Note that since an operator cannot return different types dependent upon the value being returned if you really wanted to try and directly return a numeric you would need a different operator/function. >> >> CREATE INDEX idxgin_numeric_prop ON atable USING >> gin((json_col->'numeric_prop')); > > I can add the index, but no evidence of it being used when I run a query > like this: > select * from atable where (json_col->>'numeric_prop')::numeric < 100; The index is storing text while the expression has been cast to numeric so, no, if what is shown above is exactly what you did then you would not be using the index. -- View this message in context: http://postgresql.1045698.n5.nabble.com/querying-within-json-tp5825042p5825055.html Sent from the PostgreSQL - sql mailing list archive at Nabble.com.
On 30/10/2014 16:48, David G Johnston wrote: >>> CREATE INDEX idxgin_numeric_prop ON atable USING >>> gin((json_col->'numeric_prop')); >> I can add the index, but no evidence of it being used when I run a query >> like this: >> select * from atable where (json_col->>'numeric_prop')::numeric < 100; > The index is storing text while the expression has been cast to numeric so, > no, if what is shown above is exactly what you did then you would not be > using the index. So I tried to create the index to make it a numeric index using a cast (won't show the failed details) but failed. Any suggestions on how to do this? Tim > > > > > > -- > View this message in context: http://postgresql.1045698.n5.nabble.com/querying-within-json-tp5825042p5825055.html > Sent from the PostgreSQL - sql mailing list archive at Nabble.com. > >