Skip site navigation (1) Skip section navigation (2)

Questions on plan with INSERT/SELECT on partitioned table

From: "Connors, Bill" <BConnors(at)rochgrp(dot)com>
To: <pgsql-performance(at)postgresql(dot)org>
Subject: Questions on plan with INSERT/SELECT on partitioned table
Date: 2010-02-12 16:03:05
Message-ID: 6848376EF3611E42B309F0A3D7934BC005C8B0E4@trgmail.rochgrp.com (view raw or flat)
Thread:
Lists: pgsql-performance
I have been trying to track down a performance issue we've been having with a INSERT INTO ... SELECT query run against a partitioned table on postgres.  The problem appears to be in the plan building of the query and after some further research I think I have nailed down a simplified example of the problem.  Attached is a simple script that will build an example of our table structure load 2 records and run the explain that produces the plan in question. The query plan looks like the following:

                                         QUERY PLAN               
                                                                  
------------------------------------------------------------------
--------------------------                                        
 Result  (cost=0.00..0.01 rows=1 width=0)                         
   One-Time Filter: false                                         
                                                                  
 Nested Loop  (cost=23.50..47.08 rows=4 width=1036)               
   ->  Append  (cost=0.00..23.50 rows=2 width=520)                
         ->  Seq Scan on base  (cost=0.00..11.75 rows=1 width=520)
               Filter: (id = 1)                                   
         ->  Seq Scan on base_1 base  (cost=0.00..11.75 rows=1 width=520)                                                           
               Filter: (id = 1)                                   
   ->  Materialize  (cost=23.50..23.52 rows=2 width=520)          
         ->  Append  (cost=0.00..23.50 rows=2 width=520)          
               ->  Seq Scan on another  (cost=0.00..11.75 rows=1 width=520)                                                         
                     Filter: (id = 1)                             
               ->  Seq Scan on another_1 another  (cost=0.00..11.75 rows=1 width=520)                                               
                     Filter: (id = 1)                             
                                                                  
 Result  (cost=23.50..47.08 rows=1 width=1036)                    
   One-Time Filter: false                                         
   ->  Nested Loop  (cost=23.50..47.08 rows=1 width=1036)         
         ->  Append  (cost=0.00..23.50 rows=2 width=520)          
               ->  Seq Scan on base  (cost=0.00..11.75 rows=1 width=520)                                                            
                     Filter: (id = 1)                             
               ->  Seq Scan on base_1 base  (cost=0.00..11.75 rows=1 width=520)                                                     
                     Filter: (id = 1)                             
         ->  Materialize  (cost=23.50..23.52 rows=2 width=520)    
               ->  Append  (cost=0.00..23.50 rows=2 width=520)    
                     ->  Seq Scan on another  (cost=0.00..11.75 rows=1 width=520)                                                   
                           Filter: (id = 1)                       
                     ->  Seq Scan on another_1 another  (cost=0.00..11.75 rows=1 width=520)                                         
                           Filter: (id = 1)                       
                                                                  
 Result  (cost=23.50..47.08 rows=1 width=1036)                    
   One-Time Filter: false                                         
   ->  Nested Loop  (cost=23.50..47.08 rows=1 width=1036)
         ->  Append  (cost=0.00..23.50 rows=2 width=520)
               ->  Seq Scan on base  (cost=0.00..11.75 rows=1 width=520)
                     Filter: (id = 1)
               ->  Seq Scan on base_1 base  (cost=0.00..11.75 rows=1 width=520)
                     Filter: (id = 1)
         ->  Materialize  (cost=23.50..23.52 rows=2 width=520)
               ->  Append  (cost=0.00..23.50 rows=2 width=520)
                     ->  Seq Scan on another  (cost=0.00..11.75 rows=1 width=520)
                           Filter: (id = 1)
                     ->  Seq Scan on another_1 another  (cost=0.00..11.75 rows=1 width=520)
                           Filter: (id = 1)
(45 rows)


The problem appears to be the multiple Result sections.  I don't understand why this is happening but I do know that a new results section occurs for each new partition you add.  The result is that in my actual system where we have a couple hundred partitions this query takes minutes to plan.  I've tried this on a Dell (24 core 2.66 GHz) with 192 GB of RAM running postgres 8.3.7 and an IBM 570 (16 core 1.6 Ghz Power 5) with 16 GB of RAM running postgres 8.4.2 both running RedHat Enterprise 5.0 and both take what I would consider way to long to generate the plan.

The 8.3.7 version has constraint exclusion on and the 8.4.2 version has constraint exclusion partial.



Attachment: test.sql
Description: application/octet-stream (1.9 KB)

Responses

pgsql-performance by date

Next:From: Karl DenningerDate: 2010-02-12 16:05:45
Subject: Re: 512,600ms query becomes 7500ms... but why? Postgres 8.3 query planner quirk?
Previous:From: Robert HaasDate: 2010-02-12 15:49:16
Subject: Re: Re: Faster CREATE DATABASE by delaying fsync (was 8.4.1 ubuntu karmic slow createdb)

Privacy Policy | About PostgreSQL
Copyright © 1996-2014 The PostgreSQL Global Development Group