On Mon, Dec 7, 2020 at 4:00 PM David G. Johnston <david.g.johns...@gmail.com> wrote:
> On Mon, Dec 7, 2020 at 4:49 PM Ken Tanzer <ken.tan...@gmail.com> wrote: > >> >> >> On Mon, Dec 7, 2020 at 3:22 PM David G. Johnston < >> david.g.johns...@gmail.com> wrote: >> >>> On Mon, Dec 7, 2020 at 4:13 PM Steve Baldwin <steve.bald...@gmail.com> >>> wrote: >>> >>>> Try: >>>> >>>> select _message_body->'Charges'->>'Name' from ... >>>> >>> >>> Not so much..."Charges" is an array so "->>" doesn't do anything useful. >>> >>> The OP needs to use "json_array_elements" to navigate past the array and >>> get to the next layer of the json where ->>'Name' will then work. >>> >>> >> Thank you David. I had tried that function without much luck. But with >> your inspiration, I made progress and got to this: >> >> select >> _message_exchange_id,jsonb_array_elements(_message_body->'Charges')->>'Name' >> FROM message_import_court_case WHERE _message_exchange_id = 1296; >> _message_exchange_id | ?column? >> ----------------------+-------------------------------------------- >> 1296 | Possession Of Burglary Tools >> 1296 | Burglary In The Second Degree (Commercial) >> (2 rows) >> >> But what I really want is one line per message, with the charges in an >> array. I can't seem to find the right syntax to make this work: >> >> => select >> _message_exchange_id,array_agg(jsonb_array_elements(_message_body->'Charges')->>'Name') >> FROM message_import_court_case WHERE _message_exchange_id = 1296; >> ERROR: column "message_import_court_case._message_exchange_id" must >> appear in the GROUP BY clause or be used in an aggregate function >> LINE 1: select _message_exchange_id,array_agg(jsonb_array_elements(_... >> ^ >> >> => select >> _message_exchange_id,array_agg(jsonb_array_elements(_message_body->'Charges')->>'Name') >> FROM message_import_court_case WHERE _message_exchange_id = 1296 GROUP BY 1; >> ERROR: set-valued function called in context that cannot accept a set >> >> => select _message_exchange_id,(SELECT >> array_agg(jsonb_array_elements(_message_body->'Charges')->>'Name')) FROM >> message_import_court_case WHERE _message_exchange_id = 1296 GROUP BY 1; >> ERROR: set-valued function called in context that cannot accept a set >> >> => select _message_exchange_id,(SELECT >> array_agg(jsonb_array_elements(_message_body->'Charges')->>'Name')) FROM >> message_import_court_case WHERE _message_exchange_id = 1296; >> ERROR: column "message_import_court_case._message_exchange_id" must >> appear in the GROUP BY clause or be used in an aggregate function >> LINE 1: select _message_exchange_id,(SELECT array_agg(jsonb_array_el... >> >> >> > Sub-queries are a simple solution to get around the "set-valued function" > restriction. > > The more direct way is to place the set-valued function in the FROM clause > where it wants to be, by using LATERAL (the keyword itself can be implied > when dealing with functions) > > select array_agg(e->>'key') from (values > ('[{"key":"val"},{"key":"val2"}]'::jsonb)) val (v), jsonb_array_elements(v) > jae (e) > > David J. > > OK, let me try asking again. (I'm trying to actually get something that works.) So given an example like this: CREATE TEMP TABLE foo ( id INTEGER, js JSONB ); INSERT INTO foo (id,js) VALUES (1, '[ {"key":"r1kval","key2":"r1k2val"}, {"key":"r1kval2","key2":"r1k2val2"} ]'); INSERT INTO foo (id,js) VALUES (2, '[ {"key":"r2kval","key2":"r2k2val"}, {"key":"r2kval2","key2":"r2k2val2"} ]'); Can anyone help me with a working query (preferably with the least cumbersome syntax possible!) that would return these values (the key2 values) as array text elements: id Agg_val ---- ------------------------ 1 {r1k2val,r1k2val2} 2 {r2k2val,r2k2val} (2 rows) Thank you! Ken -- AGENCY Software A Free Software data system By and for non-profits *http://agency-software.org/ <http://agency-software.org/>* *https://demo.agency-software.org/client <https://demo.agency-software.org/client>* ken.tan...@agency-software.org (253) 245-3801 Subscribe to the mailing list <agency-general-requ...@lists.sourceforge.net?body=subscribe> to learn more about AGENCY or follow the discussion.