Partitioning and postgres_fdw optimisations for multi-tenancy

From: Alexey Kondratov <a(dot)kondratov(at)postgrespro(dot)ru>
To: pgsql-hackers(at)lists(dot)postgresql(dot)org
Subject: Partitioning and postgres_fdw optimisations for multi-tenancy
Date: 2020-07-13 19:18:00
Message-ID: 9998c3af9fdb5f7d62a6c7ad0fcd9142@postgrespro.ru
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-hackers

Hi Hackers,

The idea of achieving Postgres scaling via sharding using postgres_fdw +
partitioning got a lot of attention last years. Many optimisations have
been done in this direction: partition pruning, partition-wise
aggregates / joins, postgres_fdw push-down of LIMIT, GROUP BY, etc. In
many cases they work really nice.

However, still there is a vast case, where postgres_fdw + native
partitioning doesn't perform so good — Multi-tenant architecture. From
the database perspective it is presented well in this Citus tutorial
[1]. The main idea is that there is a number of tables and all of them
are sharded / partitioned by the same key, e.g. company_id. That way, if
every company mostly works within its own data, then every query may be
effectively executed on a single node without a need for an internode
communication.

I built a simple two node multi-tenant schema for tests, which can be
easily set up with attached scripts. It creates three tables (companies,
users, documents) distributed over two nodes. Everything can be found in
this Gist [2] as well.

Some real-life test queries show, that all single-node queries aren't
pushed-down to the required node. For example:

SELECT
*
FROM
documents
INNER JOIN users ON documents.user_id = users.id
WHERE
documents.company_id = 5
AND users.company_id = 5;

executed as following

QUERY PLAN
-------------------------------------------------------
Nested Loop
Join Filter: (documents.user_id = users.id)
-> Foreign Scan on users_node2 users
-> Materialize
-> Foreign Scan on documents_node2 documents

i.e. it uses two foreign scans and does the final join locally. However,
once I specify target partitions explicitly, then the entire query is
pushed down to the foreign node:

QUERY PLAN
---------------------------------------------------------
Foreign Scan
Relations: (documents_node2) INNER JOIN (users_node2)

Execution time is dropped significantly as well — by more than 3 times
even for this small test database. Situation for simple queries with
aggregates or joins and aggregates followed by the sharding key filter
is the same. Something similar was briefly discussed in this thread [3].

IIUC, it means that push-down of queries through the postgres_fdw works
perfectly well, the problem is with partition-wise operation detection
at the planning time. Currently, partition-wise aggregate routines,
e.g., looks for a GROUP BY and checks whether sharding key exists there
or not. After that PARTITIONWISE_AGGREGATE_* flag is set. However, it
doesn't look for a content of WHERE clause, so frankly speaking it isn't
a problem, this functionality is not yet implemented.

Actually, sometimes I was able to push down queries with aggregate
simply by adding an additional GROUP BY with sharding key, like this:

SELECT
count(*)
FROM
documents
WHERE
company_id = 5
GROUP BY company_id;

where this GROUP BY obviously doesn't change a results, it just allows
planner to choose from more possible paths.

Also, I have tried to hack it a bit and forcedly set
PARTITIONWISE_AGGREGATE_FULL for this particular query. Everything
executed fine and returned result was correct, which means that all
underlying machinery is ready.

That way, I propose a change to the planner, which will check whether
partitioning key exist in the WHERE clause and will set
PARTITIONWISE_AGGREGATE_* flags if appropriate. The whole logic may look
like:

1. If the only one condition by partitioning key is used (like above),
then it is PARTITIONWISE_AGGREGATE_FULL.
2. If several conditions are used, then it should be
PARTITIONWISE_AGGREGATE_PARTIAL.

I'm aware that WHERE clause may be extremely complex in general, but we
could narrow this possible optimisation to the same restrictions as
postgres_fdw push-down "only WHERE clauses using built-in operators and
functions will be considered for execution on the remote server".

Although it seems that it will be easier to start with aggregates,
probably we should initially plan a more general solution? For example,
check that all involved tables are filtered by partitioning key and push
down the entire query if all of them target the same foreign server.

Any thoughts?

[1]
https://docs.citusdata.com/en/v9.3/get_started/tutorial_multi_tenant.html
[2] https://gist.github.com/ololobus/8fba33241f68be2e3765d27bf04882a3
[3]
https://www.postgresql.org/message-id/flat/CAFT%2BaqL1Tt0qfYqjHH%2BshwPoW8qdFjpJ8vBR5ABoXJDUcHyN1w%40mail.gmail.com

Regards
--
Alexey Kondratov

Postgres Professional https://www.postgrespro.com
Russian Postgres Company

Attachment Content-Type Size
init1.sql text/plain 1.9 KB
init2.sql text/plain 1.9 KB
load.sql text/plain 535 bytes
queries.sql text/plain 2.1 KB
setup.sh text/plain 825 bytes

Responses

Browse pgsql-hackers by date

  From Date Subject
Next Message David G. Johnston 2020-07-13 19:57:27 Re: Default setting for enable_hashagg_disk
Previous Message Tom Lane 2020-07-13 19:01:50 Re: Proposal: Automatic partition creation