Re: how to "explain" some ddl

From: Michel Pelletier <pelletier(dot)michel(at)gmail(dot)com>
To: Marc Millas <marc(dot)millas(at)mokadb(dot)com>
Cc: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>, "pgsql-general(at)lists(dot)postgresql(dot)org" <pgsql-general(at)lists(dot)postgresql(dot)org>
Subject: Re: how to "explain" some ddl
Date: 2020-07-20 14:28:09
Message-ID: CACxu=v+NXCKsLiY=u70aZXhM5jz0Of4Y2iLHE0YTVwKZUQhCgw@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

Marc,

If you add a check constraint that proves the new child partition has no
out of bounds rows, then the ATTACH PARTITION will not block:

"Before running the ATTACH PARTITION command, it is recommended to create a
CHECK constraint on the table to be attached matching the desired partition
constraint. That way, the system will be able to skip the scan to validate
the implicit partition constraint. Without the CHECK constraint, the table
will be scanned to validate the partition constraint while holding an ACCESS
EXCLUSIVE lock on that partition and a SHARE UPDATE EXCLUSIVE lock on the
parent table. It may be desired to drop the redundant CHECK constraint
after ATTACH PARTITION is finished."

https://www.postgresql.org/docs/current/ddl-partitioning.html

As for your high dimension table with lots of indexes, are you sure they
are all being used? I almost always find my legacy customers have many
indexes that are constantly being updated but are never used by their
applications due to either "framework confusion" or just overzealous
indexing. Here's a good article by Laurenze Albe on the subject:

https://www.cybertec-postgresql.com/en/get-rid-of-your-unused-indexes/

-Michel

On Tue, Jul 14, 2020 at 12:32 PM Marc Millas <marc(dot)millas(at)mokadb(dot)com> wrote:

> Hi Tom,
> a few tests later.
> Looks like when you add a partition as default, all tupples of it are
> read, even if there is an index on the column that is the partition key.
> this do explain our attach time. We are going to clean the default
> partition...
>
> regards,
>
> Marc MILLAS
> Senior Architect
> +33607850334
> www.mokadb.com
>
>
>
> On Tue, Jul 14, 2020 at 7:05 PM Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> wrote:
>
>> Marc Millas <marc(dot)millas(at)mokadb(dot)com> writes:
>> > We would like to understand where an alter table attach partition spend
>> its
>> > time.
>> > to my understanding, explain doesnt do this.
>>
>> Nope :-(. As our DDL commands have gotten more complicated, there's
>> been some discussion of adding that, but nothing's really been done
>> yet.
>>
>> There is some progress-monitoring support for some DDL commands now,
>> but that's not quite the same thing.
>>
>> > for a BI job we have a partitionned table with 1800+ partitions.
>>
>> TBH I'd recommend scaling that down by at least a factor of ten.
>> We are not at a point where you can expect that all operations will
>> be cheap even with thousands of partitions. We may never be at that
>> point, although people continue to chip away at the bottlenecks.
>>
>> regards, tom lane
>>
>

In response to

Browse pgsql-general by date

  From Date Subject
Next Message Christophe Pettus 2020-07-20 14:34:57 Re: How to restore a dump containing CASTs into a database with a new user?
Previous Message Thomas Kellerer 2020-07-20 14:22:00 Re: Logical replication from 11.x to 12.x and "unique key violations"