From: | keith anderson <kwj(dot)anderson(at)yahoo(dot)co(dot)uk> |
---|---|
To: | "pgsql-performance(at)postgresql(dot)org" <pgsql-performance(at)postgresql(dot)org> |
Subject: | Re: Partitioning Optimizer Questions and Issues |
Date: | 2019-02-11 08:05:50 |
Message-ID: | 1270348147.2230544.1549872350935@mail.yahoo.com |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-performance |
Thanks for the feedback Justin.
You are right, the most-common-values list is empty for my test case and so it is using n_distinct for the 'id IN()' scenario.And I can see that with the pg_class.reltuples and the pg_stats.histogram_bounds values how the optimizer can conclude with my range query that only 1 in 5 entries in my range query are in each individual partition.
However, I can also see that the pg_stats.n_distinct value for tablea shows -1, as do all the individual child partitions. In my opinion it makes sense for the optimizer when using n_distinct on partitioned tables to use the n_distinct value of the parent table level when estimating row counts rather than a sum of the partition level statistics. Or can someone come up with a good reason to avoid this?
A couple of examples of different data in a partitioned table:
- Unique identifier -> if providing a single value in a query -> using n_distinct from parent will estimate 1, using child tables will be 1 * (number of partitions). Use of parent table would be correct.- Date of activity, with 1000 records per day -> if providing a single day to the query -> using n_distinct from parent would show 1000 rows returned, using child tables will be 1000 * (number of partitions). Use of parent table n_distinct is correct.
Perhaps when querying on columns that are part of the partition logic you could use the partition level stats, but I think the vast majority of the time, using the parent statistics would be much more reliable/accurate than summing across partitions.
In terms of the partition strategy, I agree that it should be done with a view to helping performance improve. I will look into more detail at your suggestions, but in general it is very hard to use effectively as there are competing priorities:
- I would like to not have to manage massive numbers of partitions- I would like to be able to archive data easily using date (a big plus point to the existing date partitioning strategy)- It is hard in most cases to come up with a partition strategy that allows for partition elimination e.g. consider a common 'transaction record' table with a primary key, an account identifier, and a date -> it is natural to want to be able to query on any one of these, but as things stand it cannot be achieved performantly with partitioning.
Global index support feels like it has potential to resolve many of the issues I have with partitioning (beyond the optimizer concern above). I assume this has been discussed and rejected though by the community?
I've attached as a file the original test script.
Keith
On Friday, 8 February 2019, 13:05:04 GMT, Justin Pryzby <pryzby(at)telsasoft(dot)com> wrote:
On Fri, Feb 08, 2019 at 11:13:51AM +0000, keith anderson wrote:
> So to summarise the findings/questions from above:
> - It seems like the Postgres optimizer sometimes uses the partition level statistics, and sometimes the global table level statistics? Or is it using something else?- With partitioning tables with unique identifier and retrieving explicitly on those identifiers, at present the optimizer will always understimate the selectivity and overestimate the rows returned. This inaccuracy increases in proportion to the number of partitions.- As a result, when joining to other tables, you are liable to hitting sequential scans. This becomes more likely as you have more partitions or if join to more partitioned tables (note I am aware I could try and tune random_page_cost to try and prevent this).- To me in the examples queries described above, it makes sense to use the partition statistics for the partition level access strategy, but the global statistics when estimating the actual rows returned by all the individual partition queries. Is there a reason not to do this? Or do others believe the optimizer is doing the right thing here?
> And then some general questions:
> - How do other people use partitioning but without a significant performance disadvantage on reading the data? Is there something else I should be doing here to achieve the same thing without the overhead? At present my reads have increased optimization cost (as it needs to optimize access to each partition) and also execution cost (access the index on every partition). Even without the optimizer issues described above, the cost of reading simple data is extremely high relative to non-partitioned data (unless you use the partition key as a filter for each table to eliminate those partitions).- Is there any chance/plan to add global indexes to postgres? If so would that impact significantly the cost of the partition drop e.g. to clean up the index.
> Thanks in advance for any feedback/support,
An equality or IN() query will use the pg_stats most-common-values list,
whereas a range query will use the histogram.
The tables probably doesn't have complete MCV list. By default, that's limited
to 100 entries. Since the maximum allowed by ALTER..SET STATISTICS is 10k, I
don't think it'll help to change it (at least for your production use case).
Each partition's rowcount appears to be estimated from its ndistinct, and not
from its content, so each is estimated as having about the same rowcount.
Your partitions are sharing a sequence for their ID column, which causes the
DEFAULT IDs to be unique...but their global uniqueness isn't enforced nor
guaranteed.
Note, in postgres11, it's possible to create an index on the parent table.
It's NOT a global index, but it can be unique if it includes the partition key.
I don't know how closely your example describes your real use case, but I don't
think that helps with your example; it doesn't seems useful to partition on a
serial column.
You seem to be adding unnecessary CHECK constraints that duplicate the
partition bounds. Note, it's still useful to include CHECK constraints on key
column if you're planning on DETACHing and re-ATTACHing the partitions, in
order to avoid seqscan to verify tuples don't violate specified bounds.
You might need to rethink your partitioning scheme - you should choose one that
causes performance to improve, and probably naturally includes the partition
key in most queries.
Perhaps you'd use 2 levels of partitioning: a RANGE partition by date, which
allows for archiving, and a HASH partition by ID, which allows for partition
pruning. Note that it's also possible to partition on multiple keys, like
RANGE(id,date) - I don't think that's useful here, though. PG11 also allows a
"default" partition.
Or perhaps you could partition by RANGE(date) but add CHECK constraints on ID,
after the table is fully populated, to optimize queries by allowing for
partition pruning.
Or you could maybe change the ID column to include the timestamp (like BIND
zonesfiles YYYYMMDDNNNNNNNN). You'd set a bigint sequence on each partition's
ID as default to the beginning of the month. A bigint is enough to handle
5*10^4 times your volume: 20190401000020111222. (I think this is trying to be
unnecessarily clever, unless there's some reason the other two ideas don't
work.)
Justin
Attachment | Content-Type | Size |
---|---|---|
partitionExample.sql | application/sql | 5.7 KB |
From | Date | Subject | |
---|---|---|---|
Next Message | Jung, Jinho | 2019-02-11 22:29:36 | Performance regressions found using sqlfuzz |
Previous Message | Tom Lane | 2019-02-11 01:22:45 | Re: dsa_allocate() faliure |