I am working to build a drag and drop feature for a client project and need my data to look like this:
[ [Array(10)], [Array(5)], [Array(5)], [Array(5)], [Array(5)] ]
Where each array will look like this (each of these are representing patients):
[ {id: 1, reccomendations: [array] } ]
The recommendations array, one level deeper, will look like this:
["providerName1", "providerName2", "providerName3"]
My database is set up as such:
Patient Table
+----+-----------+
| id | bucket_id |
+----+-----------+
| 1 | 1 |
| 2 | 2 |
| 3 | 3 |
| 4 | 4 |
| 5 | 5 |
| 6 | 6 |
| 7 | 2 |
| 8 | 3 |
| 9 | 4 |
| 10 | 5 |
+----+-----------+
patient_provider Table
provider_id references provider.id
patient_id references patiend.id
+----+-------------+-------------+
| id | provider_id | patient_id |
+----+-------------+-------------+
| 1 | 1 | 1 |
| 2 | 7 | 1 |
| 3 | 3 | 1 |
| 4 | 1 | 2 |
| 5 | 8 | 3 |
| 6 | 7 | 3 |
| 7 | 3 | 4 |
| 8 | 2 | 5 |
| 9 | 11 | 5 |
| 10 | 1 | 6 |
+----+-------------+-------------+
Provider Table
provider_id references provider.id
patient_id references patiend.id
+----+-------------+-------------+
| id | provider_id | patient_id |
+----+-------------+-------------+
| 1 | 1 | 1 |
| 2 | 7 | 1 |
| 3 | 3 | 1 |
| 4 | 1 | 2 |
| 5 | 8 | 3 |
| 6 | 7 | 3 |
| 7 | 3 | 4 |
| 8 | 2 | 5 |
| 9 | 11 | 5 |
| 10 | 1 | 6 |
+----+-------------+-------------+
Provider Table
There are more rows and columns than this, but this is the only column I need
+----+-----------+
| id | program |
+----+-----------+
| 1 | blue |
| 2 | red |
| 3 | green |
| 4 | yellow |
| 5 | pink |
| 6 | teal |
+----+-----------+
I've run this:
SELECT "patient".id, ARRAY_AGG(DISTINCT("provider".program)) as providers FROM "patient"
LEFT JOIN "patient_provider" ON "patient_provider".patient_id = "patient".id
LEFT JOIN "provider" ON "provider".id = "patient_provider".provider_id
GROUP BY "patient".id
ORDER BY "patient".id ASC;
Which will get me the array of providers per patient.
I have also run this:
SELECT JSON_AGG("patient") as patient FROM "patient"
WHERE "patient".bucket_id =1;
With this, I can get all the buckets/columns and the patients that belong in those columns.
I haven't been able to find a way to combine the two into the data structure that I need. I've done some reading on JSON Build Objects - would this be the way to go? How would I do that? I am also open to doing this workflow on the server-side, using a function to splice and manually get me the data structure that I need...if that is the better way to do it. If you think that that is the way to go, how would I do it?
I'll buy coffee for whoever can help me with this! I'd love to make my clients' day by building this feature out for them!
I recreated your case with the following statements
create table patient (id serial, bucket_id int);
insert into patient (bucket_id) values (1);
insert into patient (bucket_id) values (2);
insert into patient (bucket_id) values (3);
insert into patient (bucket_id) values (4);
insert into patient (bucket_id) values (5);
insert into patient (bucket_id) values (6);
insert into patient (bucket_id) values (2);
insert into patient (bucket_id) values (3);
insert into patient (bucket_id) values (4);
insert into patient (bucket_id) values (5);
create table patient_provider (id serial, provider_id int, patient_id int);
insert into patient_provider (provider_id, patient_id) values (1,1);
insert into patient_provider (provider_id, patient_id) values (7,1);
insert into patient_provider (provider_id, patient_id) values (3,1);
insert into patient_provider (provider_id, patient_id) values (1,2);
insert into patient_provider (provider_id, patient_id) values (8,3);
insert into patient_provider (provider_id, patient_id) values (7,3);
insert into patient_provider (provider_id, patient_id) values (3,4);
insert into patient_provider (provider_id, patient_id) values (2,5);
insert into patient_provider (provider_id, patient_id) values (11,5);
insert into patient_provider (provider_id, patient_id) values (1,6);
create table provider (id serial, program varchar);
insert into provider (program) values ('blue');
insert into provider (program) values ('red');
insert into provider (program) values ('green');
insert into provider (program) values ('yellow');
insert into provider (program) values ('pink');
insert into provider (program) values ('teal');
Now, taking your first query, and using the json_build_object
function, you can achieve the {id: 1, reccomendations: [array] }
(the external array is not really needed). The query is the below
SELECT json_build_object('id',"patient".id, 'reccomendations', ARRAY_AGG(DISTINCT("provider".program))) as obj FROM "patient"
LEFT JOIN "patient_provider" ON "patient_provider".patient_id = "patient".id
LEFT JOIN "provider" ON "provider".id = "patient_provider".provider_id
GROUP BY "patient".id
ORDER BY "patient".id ASC
And the result is
obj
-------------------------------------------------------
{"id" : 1, "reccomendations" : ["blue","green",null]}
{"id" : 2, "reccomendations" : ["blue"]}
{"id" : 3, "reccomendations" : [null]}
{"id" : 4, "reccomendations" : ["green"]}
{"id" : 5, "reccomendations" : ["red",null]}
{"id" : 6, "reccomendations" : ["blue"]}
{"id" : 7, "reccomendations" : [null]}
{"id" : 8, "reccomendations" : [null]}
{"id" : 9, "reccomendations" : [null]}
{"id" : 10, "reccomendations" : [null]}
(10 rows)
Now, if you want to aggregate the above results, you can do so with the json_agg
function. This is the overall code
With single_objects as (
SELECT json_build_object('id',"patient".id, 'reccomendations', ARRAY_AGG(DISTINCT("provider".program))) as obj FROM "patient"
LEFT JOIN "patient_provider" ON "patient_provider".patient_id = "patient".id
LEFT JOIN "provider" ON "provider".id = "patient_provider".provider_id
GROUP BY "patient".id
ORDER BY "patient".id ASC
)
select json_agg(obj) from single_objects
and result
json_agg
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
[{"id" : 1, "reccomendations" : ["blue","green",null]}, {"id" : 2, "reccomendations" : ["blue"]}, {"id" : 3, "reccomendations" : [null]}, {"id" : 4, "reccomendations" : ["green"]}, {"id" : 5, "reccomendations" : ["red",null]}, {"id" : 6, "reccomendations" : ["blue"]}, {"id" : 7, "reccomendations" : [null]}, {"id" : 8, "reccomendations" : [null]}, {"id" : 9, "reccomendations" : [null]}, {"id" : 10, "reccomendations" : [null]}]
(1 row)
If you really need the extra array encapsulation for each id, you just need to add a json_build_array
function to the json_build_object
call mentioned above. Full query
With single_objects as (
SELECT json_build_array(json_build_object('id',"patient".id, 'reccomendations', ARRAY_AGG(DISTINCT("provider".program)))) as obj FROM "patient"
LEFT JOIN "patient_provider" ON "patient_provider".patient_id = "patient".id
LEFT JOIN "provider" ON "provider".id = "patient_provider".provider_id
GROUP BY "patient".id
ORDER BY "patient".id ASC
)
select json_agg(obj) from single_objects
End result
json_agg
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
[[{"id" : 1, "reccomendations" : ["blue","green",null]}], [{"id" : 2, "reccomendations" : ["blue"]}], [{"id" : 3, "reccomendations" : [null]}], [{"id" : 4, "reccomendations" : ["green"]}], [{"id" : 5, "reccomendations" : ["red",null]}], [{"id" : 6, "reccomendations" : ["blue"]}], [{"id" : 7, "reccomendations" : [null]}], [{"id" : 8, "reccomendations" : [null]}], [{"id" : 9, "reccomendations" : [null]}], [{"id" : 10, "reccomendations" : [null]}]]
(1 row)