Re: two queries and dual cpu (perplexed) - Mailing list pgsql-performance

From John A Meinel
Subject Re: two queries and dual cpu (perplexed)
Date
Msg-id 4267C34D.9010705@arbash-meinel.com
Whole thread Raw
In response to Re: two queries and dual cpu (perplexed)  ("Shoaib Burq (VPAC)" <sab@vpac.org>)
Responses Re: two queries and dual cpu (perplexed)
Re: two queries and dual cpu (perplexed)
List pgsql-performance
Shoaib Burq (VPAC) wrote:

>Just tried it with the following changes:
>
>shared_buffers = 10600
>work_mem = 102400
>enable_seqscan = false
>
>still no improvement
>
>Ok here's the Plan with the enable_seqscan = false:
>ausclimate=# explain ANALYZE  select count(*) from "getfutureausclimate";
>
>
Actually, you probably don't want enable_seqscan=off, you should try:
SET enable_nestloop TO off.
The problem is that it is estimating there will only be 44 rows, but in
reality there are 13M rows. It almost definitely should be doing a
seqscan with a sort and merge join.

Also, please attach you explain analyzes, the wrapping is really hard to
read.

I don't understand how postgres could get the number of rows that wrong.

It seems to be misestimating the number of entries in IX_ClimateId

Here:

->  Index Scan using "PK_Aus40_DEM" on "Aus40_DEM"  (cost=0.00..6.01 rows=1 width=16) (actual time=0.005..0.006 rows=1
loops=13276368)
    Index Cond: ("outer"."AusPosNumber" = "Aus40_DEM"."AusPosNumber")
->  Index Scan using "PK_CurrentAusClimate" on "CurrentAusClimate"  (cost=0.00..46.20 rows=11 width=14) (actual
time=0.007..0.009rows=1 loops=13276368) 

The first index scan is costing you 0.006*13276368=79s, and the second one is 119s.

I can't figure out exactly what is where from the formatting, but the query that seems misestimated is:
->  Index Scan using "IX_ClimateId" on "ClimateChangeModel40"  (cost=0.00..1063711.75 rows=265528 width=20) (actual
time=28.311..17212.703rows=13276368 loops=1) 
    Index Cond: ("outer"."ClimateId" = "ClimateChangeModel40"."ClimateId")

Is there an unexpected correlaction between
ClimateChangeModel40"."ClimateId" and whatever "outer" is at this point?

John
=:->


Attachment

pgsql-performance by date:

Previous
From: "Mohan, Ross"
Date:
Subject: Re: Joel's Performance Issues WAS : Opteron vs Xeon
Next
From: Richard van den Berg
Date:
Subject: Re: When are index scans used over seq scans?