On Mon, Feb 27, 2023 at 6:22 PM Thorsten Glaser <tg@evolvis.org> wrote:
Not about the DISTINCTs. I haven’t used JOIN much (usually WHERE as inner join) nor on tables this massive, and this is my second foray into aggregate functions only.
Fair.
Consider this then as a jumping point to a more precise query form:
create table base (base_id integer primary key, base_val text not null);
insert into base values (1, 'one');
create table subone (subone_id serial primary key, base_id integer, subone_value text not null);
insert into subone (base_id, subone_value) values (1, 'subone-one'), (1, 'subone-two');
create table subtwo (subtwo_id serial primary key, base_id integer, subtwo_value text not null);
insert into subtwo (base_id, subtwo_value) values (1, 'subtwo-one'), (1, 'subtwo-two');
--BAD cross joining going on with multiple one-to-many relationships
select * from base join subone using (base_id) join subtwo using (base_id); -- not good
--GOOD, only joining one-to-one relationships
select jsonb_build_object('base_id', base_id, 'subone_arr', subone_arr, 'subtwo_arr', subtwo_arr) from base join lateral (select json_agg(jsonb_build_object('key', subone_value) order by subone_value) from subone where subone.base_id = base.base_id) as so (subone_arr) on true join (select base_id, json_agg(subtwo_value order by subtwo_value desc) from subtwo group by base_id) as st (base_id, subtwo_arr) using (base_id)
I used a mix of forms in the two joins, and there are other variants, but the basic concept holds - produce single rows in subqueries then join those various single rows together to produce your desired json output.