Re: query multiple schemas

From: Marcos Pegoraro <marcos(at)f10(dot)com(dot)br>
To: Norbert Sándor <sandor(dot)norbert(at)erinors(dot)com>
Cc: pgsql-general(at)lists(dot)postgresql(dot)org
Subject: Re: query multiple schemas
Date: 2024-04-23 12:41:25
Message-ID: CAB-JLwYSDNPJwss7=0LbHtpc4BzBpmfTYA2L8b58wV1Gqq96uQ@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

Em dom., 21 de abr. de 2024 às 17:12, Norbert Sándor <
sandor(dot)norbert(at)erinors(dot)com> escreveu:

> Hello,
>
> I have a database with multiple tenants with a separate schema for each
> tenant.
> The structure of each schema is identical, the tenant ID is the name of
> the schema.
>
> What I would like to achieve is to able to query tables in all schemas at
> once with the tenant IDs added to the result set.
>
I have a similar structure and do my multi tenant queries this way.
The only problem I see is that we have to define every result type, because
I return a record, but it runs fine.

create function sql_per_tenant(sql text, tenants text[]) returns setof
record language plpgsql AS $function$
declare
Result record;
schemas text;
begin
for schemas in select unnest(tenants) loop
execute Format('set local search_path to %s, public;', schemas);
for Result in execute Format('select $$%1$s$$ tenant, * from (%2$s) x',
schemas, sql) loop
return next Result;
end loop;
end loop;
end;$function$;

select * from sql_per_tenant('select Order_ID, sum(Value) from Orders inner
join Items using(Order_ID)
where Due_Date = Current_Date','{cus_001,cus_035,cus_175}')
as (SchemaName text, Order_ID integer, sum_of_items Numeric)

regards
Marcos

In response to

Browse pgsql-general by date

  From Date Subject
Next Message David G. Johnston 2024-04-23 13:27:00 Re: Password forgotten
Previous Message Hans Schou 2024-04-23 12:18:43 Re: Password forgotten