Обсуждение: query multiple schemas

Поиск
Список
Период
Сортировка

query multiple schemas

От
Norbert Sándor
Дата:

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 experimented with typed solutions like described in https://dev.to/staab/how-to-query-multiple-schemas-with-postgresql-28kj without much success.
So I turned to a more dynamic JSON-based solution.

Please note that I'm new to plpgsql, so any (even a less related) advice is welcome :)

My current experimental function is:

CREATE OR REPLACE FUNCTION demo.tenant_union_query(tbl anyelement)

RETURNS setof json AS $func$

declare

_select text;

begin

_select := (select

string_agg(

format('select t.*, %L tenantId from %I.%I t', schema_name, schema_name, pg_typeof(tbl)),

E'\n' || ' union all ' || E'\n')

from (

SELECT schema_name

FROM information_schema.schemata

where schema_name not in ('information_schema') and schema_name not like 'pg_%'

) tenants

);

return query execute 'select row_to_json(r) from (' || _select || ') as r';

END;

$func$ LANGUAGE plpgsql;

And this is how I use it to query a "usual" result-set-like result with the tenant ID in the 1st column, followed by the fields from the given table:

select r->>'tenantid' tenantId, json_populate_record(null::mytable, r) from tenant_union_query(null::mytable) r order by tenantId; -- (1)

The above solution seems to work, my questions are:

  1. Is there a better way to achieve the same functionality? Maybe without using JSON as an intermediate representation?
  2. Is there a way to further simplify the usage, like instead of the query (1) above something more simple, like: select * from tenant_union_query_2(null::mytable) order by tenantId;

Thanks for your help in advance.
Best regards,
Norbi

Re: query multiple schemas

От
Steve Baldwin
Дата:
Hi Norbi,

If the number of tenant schemas is reasonably static, you could write a plpgsql function to create a set of UNION ALL views with one view for each table in all tenant schemas. You could re-run the function each time a tenant schema is added. Having the set of views would allow you to query them as you would any of the underlying tables, and the query planner could likely optimise the query better. With your current function, if you needed to add a WHERE clause and the underlying tables were large, it would likely not perform as well as the UNION ALL view.

Cheers,

Steve

On Mon, Apr 22, 2024 at 6:12 AM Norbert Sándor <sandor.norbert@erinors.com> wrote:

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 experimented with typed solutions like described in https://dev.to/staab/how-to-query-multiple-schemas-with-postgresql-28kj without much success.
So I turned to a more dynamic JSON-based solution.

Please note that I'm new to plpgsql, so any (even a less related) advice is welcome :)

My current experimental function is:

CREATE OR REPLACE FUNCTION demo.tenant_union_query(tbl anyelement)

RETURNS setof json AS $func$

declare

_select text;

begin

_select := (select

string_agg(

format('select t.*, %L tenantId from %I.%I t', schema_name, schema_name, pg_typeof(tbl)),

E'\n' || ' union all ' || E'\n')

from (

SELECT schema_name

FROM information_schema.schemata

where schema_name not in ('information_schema') and schema_name not like 'pg_%'

) tenants

);

return query execute 'select row_to_json(r) from (' || _select || ') as r';

END;

$func$ LANGUAGE plpgsql;

And this is how I use it to query a "usual" result-set-like result with the tenant ID in the 1st column, followed by the fields from the given table:

select r->>'tenantid' tenantId, json_populate_record(null::mytable, r) from tenant_union_query(null::mytable) r order by tenantId; -- (1)

The above solution seems to work, my questions are:

  1. Is there a better way to achieve the same functionality? Maybe without using JSON as an intermediate representation?
  2. Is there a way to further simplify the usage, like instead of the query (1) above something more simple, like: select * from tenant_union_query_2(null::mytable) order by tenantId;

Thanks for your help in advance.
Best regards,
Norbi

query multiple schemas

От
"David G. Johnston"
Дата:
On Sunday, April 21, 2024, Norbert Sándor <sandor.norbert@erinors.com> wrote:


The structure of each schema is identical, the tenant ID is the name of the schema.

You’ve hit the main reason why the scheme you choose is usually avoided.  Better to just add tenant_id to your tables in the first place.  And use partitioned tables if you desire physical separation.

The above solution seems to work, my questions are:

  1. Is there a better way to achieve the same functionality? Maybe without using JSON as an intermediate representation?

In-database, I doubt it (though I didn’t study your specific solution in depth).  Json provides the easiest way to generate the virtual tables you need.

Otherwise maybe try something with say bash scripting and psql scripts; or some other client-side setup where you separate the query and the metadata lookups so the queries just return normal results and the client takes them are merges them.

David J.

Re: query multiple schemas

От
Tom Lane
Дата:
Steve Baldwin <steve.baldwin@gmail.com> writes:
> If the number of tenant schemas is reasonably static, you could write a
> plpgsql function to create a set of UNION ALL views with one view for each
> table in all tenant schemas. You could re-run the function each time a
> tenant schema is added. Having the set of views would allow you to query
> them as you would any of the underlying tables, and the query planner could
> likely optimise the query better. With your current function, if you needed
> to add a WHERE clause and the underlying tables were large, it would likely
> not perform as well as the UNION ALL view.

Another idea is to build a partitioned table comprising all the
individual tables.  This might require the tables to have all the
same owner (not sure about that) and it'd require you to store the
partition key, ie tenant, explicitly in every table which might
seem a bit wasteful.  But it'll likely outperform any other solution
for the union queries.  Notably, adding or deleting a partition would
be much less painful than redefining a UNION ALL view.

            regards, tom lane



Re: query multiple schemas

От
Dominique Devienne
Дата:
On Sun, Apr 21, 2024 at 11:12 PM Tom Lane <tgl@sss.pgh.pa.us> wrote:
Steve Baldwin <steve.baldwin@gmail.com> writes:
> If the number of tenant schemas is reasonably static, you could write a
> plpgsql function to create a set of UNION ALL views

Another idea is to build a partitioned table

Hi Norbert. I asked a [similar question][1] a while back,
and unfortunately didn't get any actionable input, perhaps
because I already mentioned in my message the options
proposed here so far. Seems like people like us, using a
dynamic number of schemas, are outliers in database-land.

In my case, the revision/version of the schema could be
different as well, which would complicate the partitioning idea.

In any case, I'm interested in what works well for you.
And if/when I get back to this issue myself, I'll do the same.

Thanks, --DD

Re: query multiple schemas

От
Dominique Devienne
Дата:
On Tue, Apr 23, 2024 at 11:08 AM Norbert Sándor <sandor.norbert@erinors.com> wrote:
> And if/when I get back to this issue myself, I'll do the same.
My current solution is not much different than the one I posted in my original question.

CREATE OR REPLACE FUNCTION tenant_query_json(tbl anyelement)

RETURNS setof json AS $func$ [...]


CREATE OR REPLACE FUNCTION tenant_query(tbl anyelement)

RETURNS table(tenantId text, record anyelement) AS $func$ [...]

Thanks for sharing Norbi. I'm not well versed in PG/PLsql, so using
`anyelement` and `returns setof / table` is interesting to see.

Regarding the type system, I don't know if PostgreSQL supports "structural" typing,
i.e. types from different schemas, despite having the same "shape", are not interoperable.
Thus your need to go through JSON to "anonymize" the types in your inner function, then
de-anonymize them (to a schema's specific type) as a record, in your outer function.

One solution in your case of homogenous tables types, is to centralize your types in
a single data-less schema, and then create each tenants tables based on those types,
i.e. all tables (across tenant schemas) share the same type. But that's speculation mostly.

--DD

CREATE [...] TABLE [...] table_name OF type_name

Re: query multiple schemas

От
Marcos Pegoraro
Дата:
Em dom., 21 de abr. de 2024 às 17:12, Norbert Sándor <sandor.norbert@erinors.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