> On 14 Sep 2024, at 10:33, Dan Kortschak <dan+pgsql@xxxxxxxxxxxx> wrote: (…) > I'm still having difficulties with the second part which is to update > the contents of the amend array in the JSON. > > So far I'm able to append the relevant details to the append array, but > I'm unable to correctly select the corrects elements from the $6 > argument, which is in the form > [{"start":<RFC3339>,"end":<RFC3339>,"data":<object>}, ...]. The first > update statement gives me broadly what I want, but includes elements of > the array that it shouldn't. (…) > If I filter on the start and end time, I end up with no element coming > through at all and the "replace" field ends up null. > > update > events > set > datastr = jsonb_set( > datastr, > '{amend}', > datastr->'amend' || jsonb_build_object( > 'time', $2::TEXT, > 'msg', $3::TEXT, > 'replace', ( > select * > from > jsonb($6::TEXT) as replacement > where > (replacement->>'start')::TIMESTAMP WITH TIME ZONE < endtime and > (replacement->>'end')::TIMESTAMP WITH TIME ZONE > starttime > ) > ) > ) > where > starttime < $5 and > endtime > $4 and > bucketrow = ( > select rowid from buckets where id = $1 > ); That’s because the replacement data is an array of objects, not a single object. You need to iterate through the array elements to build your replacement data, something like what I do here with a select (because that’s way easier to play around with): with dollar6 as ( select jsonb($$[ { "data": { "foo": 1, "bar": 2 }, "end": "2023-06-12T19:54:51Z", "start": "2023-06-12T19:54:39Z" } ]$$::text) replacement ) select * from dollar6 cross join lateral jsonb_array_elements(replacement) r where (r->>'start')::timestamptz <= current_timestamp; There are probably other ways to attack this problem, this is the one I came up with. Alban Hertroys -- If you can't see the forest for the trees, cut the trees and you'll find there is no forest.