Error in PostgreSQL: Argument of WHERE Must Not Return a Set
A query that I initially wrote didn't work since jsonb_array_elements returns a set of boolean values. Instead, we can use a LATERAL subquery to achieve our goal.
Join the DZone community and get the full member experience.
Join For FreeIn my last post, I showed how to load and query data from the Strava API in PostgreSQL, and after executing some simple queries, my next task was to query more complex part of the JSON structure.
Strava allows users to create segments, which are edited portions of road or trail where athletes can compete for time.
I wanted to write a query to find all the times that I’d run a particular segment. For example, the Akerman Road segment covers a road running North to South in Kennington/Stockwell in South London.
This segment has the ID ‘6818475’
, so we’ll need to look inside segment_efforts
and then compare the value segment.id
against this ID.
I initially wrote this query to try to find the times I’d run this segment:
SELECT id, data->'start_date' AS startDate, data->'average_speed' AS averageSpeed
FROM runs
WHERE jsonb_array_elements(data->'segment_efforts')->'segment'->>'id' = '6818475'
ERROR: argument OF WHERE must NOT RETURN a SET
LINE 3: WHERE jsonb_array_elements(data->'segment_efforts')->'segmen...
This doesn’t work since jsonb_array_elements
returns a set of boolean values, as Craig Ringer points out on Stack Overflow.
Instead, we can use a LATERAL
subquery to achieve our goal:
SELECT id, data->'start_date' AS startDate, data->'average_speed' AS averageSpeed
FROM runs r,
LATERAL jsonb_array_elements(r.data->'segment_efforts') segment
WHERE segment ->'segment'->>'id' = '6818475'
id | startdate | averagespeed
-----------+------------------------+--------------
455461182 | "2015-12-24T11:20:26Z" | 2.841
440088621 | "2015-11-27T06:10:42Z" | 2.975
407930503 | "2015-10-07T05:18:34Z" | 2.985
317170464 | "2015-06-03T04:44:59Z" | 2.842
312629236 | "2015-05-27T04:46:33Z" | 2.857
277786711 | "2015-04-02T05:25:59Z" | 2.408
226351235 | "2014-12-05T07:59:15Z" | 2.803
225073326 | "2014-12-01T06:15:21Z" | 2.929
224287690 | "2014-11-29T09:02:46Z" | 3.087
223964715 | "2014-11-28T06:18:29Z" | 2.844
(10 ROWS)
Perfect!
Published at DZone with permission of Mark Needham, DZone MVB. See the original article here.
Opinions expressed by DZone contributors are their own.
Comments