Thread: Poor performance when deleting from entity-attribute-value type master-table

Poor performance when deleting from entity-attribute-value type master-table

From
Andreas Joseph Krogh
Date:
Hi all.
 
Using PG-9.4.0 I'm seeing this trying to delete from an "entity"-master table:
 
*# explain analyze     delete from onp_crm_entity where entity_id IN (select tmp.delivery_id from temp_delete_delivery_id tmp);
                                                                    QUERY PLAN                                                                     
---------------------------------------------------------------------------------------------------------------------------------------------------
 Delete on onp_crm_entity  (cost=0.43..5673.40 rows=1770 width=12) (actual time=7.370..7.370 rows=0 loops=1)
   ->  Nested Loop  (cost=0.43..5673.40 rows=1770 width=12) (actual time=0.050..1.374 rows=108 loops=1)
         ->  Seq Scan on temp_delete_delivery_id tmp  (cost=0.00..27.70 rows=1770 width=14) (actual time=0.014..0.080 rows=108 loops=1)
         ->  Index Scan using onp_crm_entity_pkey on onp_crm_entity  (cost=0.43..3.18 rows=1 width=14) (actual time=0.010..0.011 rows=1 loops=108)
               Index Cond: (entity_id = tmp.delivery_id)
 Planning time: 0.314 ms
 Trigger for constraint onp_crm_activity_entity_id_fkey: time=4.141 calls=108
 Trigger for constraint ...
 Trigger for constraint ...
 Trigger for constraint ...
 
 
I have lots of tables referencing onp_crm_entity(entity_id) so I expect the poor performance of deleting from it is caused by all the triggers firing to check FKI-constraints.
 
Are there any ways around this or do people simply avoid having FKs in schemas like this?
 
Thanks.
 
--
Andreas Joseph Krogh
CTO / Partner - Visena AS
Mobile: +47 909 56 963
Attachment

 

 

From: pgsql-performance-owner@postgresql.org [mailto:pgsql-performance-owner@postgresql.org] On Behalf Of Andreas Joseph Krogh
Sent: Monday, February 09, 2015 4:13 PM
To: pgsql-performance@postgresql.org
Subject: [PERFORM] Poor performance when deleting from entity-attribute-value type master-table

 

Hi all.

 

Using PG-9.4.0 I'm seeing this trying to delete from an "entity"-master table:

 

*# explain analyze     delete from onp_crm_entity where entity_id IN (select tmp.delivery_id from temp_delete_delivery_id tmp);
                                                                    QUERY PLAN                                                                     
---------------------------------------------------------------------------------------------------------------------------------------------------
 Delete on onp_crm_entity  (cost=0.43..5673.40 rows=1770 width=12) (actual time=7.370..7.370 rows=0 loops=1)
   ->  Nested Loop  (cost=0.43..5673.40 rows=1770 width=12) (actual time=0.050..1.374 rows=108 loops=1)
         ->  Seq Scan on temp_delete_delivery_id tmp  (cost=0.00..27.70 rows=1770 width=14) (actual time=0.014..0.080 rows=108 loops=1)
         ->  Index Scan using onp_crm_entity_pkey on onp_crm_entity  (cost=0.43..3.18 rows=1 width=14) (actual time=0.010..0.011 rows=1 loops=108)
               Index Cond: (entity_id = tmp.delivery_id)
 Planning time: 0.314 ms
 Trigger for constraint onp_crm_activity_entity_id_fkey: time=4.141 calls=108

 Trigger for constraint ...

 Trigger for constraint ...

 Trigger for constraint ...

 

 

I have lots of tables referencing onp_crm_entity(entity_id) so I expect the poor performance of deleting from it is caused by all the triggers firing to check FKI-constraints.

 

 

Andreas, do you have indexes on FK columns in child tables?

If not – there is your problem.

 

Regards,

Igor Neyman

 

Re: Poor performance when deleting from entity-attribute-value type master-table

From
Jerry Sievers
Date:
Andreas Joseph Krogh <andreas@visena.com> writes:

> Hi all.
>
> Using PG-9.4.0 I'm seeing this trying to delete from an "entity"-master table:
>
> *# explain analyze delete from onp_crm_entity where entity_id IN (select tmp.delivery_id from temp_delete_delivery_id
tmp);
>  QUERY PLAN
>
---------------------------------------------------------------------------------------------------------------------------------------------------
> Delete on onp_crm_entity (cost=0.43..5673.40 rows=1770 width=12) (actual time=7.370..7.370 rows=0 loops=1)
>  -> Nested Loop (cost=0.43..5673.40 rows=1770 width=12) (actual time=0.050..1.374 rows=108 loops=1)
>  -> Seq Scan on temp_delete_delivery_id tmp (cost=0.00..27.70 rows=1770 width=14) (actual time=0.014..0.080 rows=108
loops=1)
>  -> Index Scan using onp_crm_entity_pkey on onp_crm_entity (cost=0.43..3.18 rows=1 width=14) (actual
time=0.010..0.011rows=1 loops=108) 
>  Index Cond: (entity_id = tmp.delivery_id)
> Planning time: 0.314 ms
> Trigger for constraint onp_crm_activity_entity_id_fkey: time=4.141 calls=108
> Trigger for constraint ...
> Trigger for constraint ...
> Trigger for constraint ...
>
>
> I have lots of tables referencing onp_crm_entity(entity_id) so I expect the poor performance of deleting from it is
causedby all the triggers firing to check 
> FKI-constraints.
>
> Are there any ways around this or do people simply avoid having FKs in schemas like this?

The classic problem is that  one/more of your referring tables is
non-trivial in size and you are missing  an index on the referring column(s).

Insure that this condition does not exist before butchering your design :-)


> Thanks.
>
> --
> Andreas Joseph Krogh
> CTO / Partner - Visena AS
> Mobile: +47 909 56 963
> andreas@visena.com
> www.visena.com
> [cid]
>

--
Jerry Sievers
Postgres DBA/Development Consulting
e: postgres.consulting@comcast.net
p: 312.241.7800


Re: Poor performance when deleting from entity-attribute-value type master-table

From
Andreas Joseph Krogh
Date:
På mandag 09. februar 2015 kl. 22:36:55, skrev Igor Neyman <ineyman@perceptron.com>:

 

 

From: pgsql-performance-owner@postgresql.org [mailto:pgsql-performance-owner@postgresql.org] On Behalf Of Andreas Joseph Krogh
Sent: Monday, February 09, 2015 4:13 PM
To: pgsql-performance@postgresql.org
Subject: [PERFORM] Poor performance when deleting from entity-attribute-value type master-table

 

Hi all.

 

Using PG-9.4.0 I'm seeing this trying to delete from an "entity"-master table:

 

*# explain analyze     delete from onp_crm_entity where entity_id IN (select tmp.delivery_id from temp_delete_delivery_id tmp);
                                                                    QUERY PLAN                                                                     
---------------------------------------------------------------------------------------------------------------------------------------------------
 Delete on onp_crm_entity  (cost=0.43..5673.40 rows=1770 width=12) (actual time=7.370..7.370 rows=0 loops=1)
   ->  Nested Loop  (cost=0.43..5673.40 rows=1770 width=12) (actual time=0.050..1.374 rows=108 loops=1)
         ->  Seq Scan on temp_delete_delivery_id tmp  (cost=0.00..27.70 rows=1770 width=14) (actual time=0.014..0.080 rows=108 loops=1)
         ->  Index Scan using onp_crm_entity_pkey on onp_crm_entity  (cost=0.43..3.18 rows=1 width=14) (actual time=0.010..0.011 rows=1 loops=108)
               Index Cond: (entity_id = tmp.delivery_id)
 Planning time: 0.314 ms
 Trigger for constraint onp_crm_activity_entity_id_fkey: time=4.141 calls=108

 Trigger for constraint ...

 Trigger for constraint ...

 Trigger for constraint ...

 

 

I have lots of tables referencing onp_crm_entity(entity_id) so I expect the poor performance of deleting from it is caused by all the triggers firing to check FKI-constraints.

 

 

Andreas, do you have indexes on FK columns in child tables?

If not – there is your problem.

 
Yes, they have indexes, but deleting 1M rows still results in calling the triggers 1M times * number of FKs...
 
--
Andreas Joseph Krogh
CTO / Partner - Visena AS
Mobile: +47 909 56 963
 
Attachment
On 02/09/2015 01:12 PM, Andreas Joseph Krogh wrote:
> Are there any ways around this or do people simply avoid having FKs in
> schemas like this?

Don't use EAV.  It's a bad design pattern, especially for you, and
you've just discovered one of the reasons why.

(In fact, I am just today dismantling an EAV database and normalizing
it, and so far application throughput is up 500%)

--
Josh Berkus
PostgreSQL Experts Inc.
http://pgexperts.com