Re: cpu_tuple_cost

From: Daniel Schuchardt <daniel_schuchardt(at)web(dot)de>
To: pgsql-performance(at)postgresql(dot)org
Subject: Re: cpu_tuple_cost
Date: 2005-03-17 09:37:05
Message-ID: d1bj3m$1s1s$1@news.hub.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

Tom Lane wrote:

>
> Reducing random_page_cost is usually the best way to get the planner to
> favor indexscans more.
>

Ok, I tried a bit with random_page_cost and I have set it to 1 to become
PG using the index on mitpln:

CIMSOFT=# ANALYSE mitpln;
ANALYZE
CIMSOFT=# SET random_page_cost=2;
SET
CIMSOFT=# EXPLAIN ANALYSE SELECT * FROM mitpln WHERE
date_to_yearmonth_dec(mpl_date)='20050';
QUERY PLAN

--------------------------------------------------------------------------------

Seq Scan on mitpln (cost=0.00..1173.78 rows=1431 width=69) (actual
time=219.000..1125.000 rows=1266 loops=1)
Filter: ((date_to_yearmonth_dec((mpl_date)::timestamp without time
zone))::text = '20050'::text)
Total runtime: 1125.000 ms
(3 rows)

CIMSOFT=# SET random_page_cost=1;
SET
CIMSOFT=# EXPLAIN ANALYSE SELECT * FROM mitpln WHERE
date_to_yearmonth_dec(mpl_date)='20050';
QUERY PLAN

--------------------------------------------------------------------------------
Index Scan using mitpln_yearmonth_dec on mitpln (cost=0.00..699.01
rows=1431 width=69) (actual time=0.000..16.000 rows=1266 loops=1)
Index Cond: ((date_to_yearmonth_dec((mpl_date)::timestamp without
time zone))::text = '20050'::text)
Total runtime: 16.000 ms
(3 rows)

CIMSOFT=# \d mitpln
Table "public.mitpln"
Column | Type | Modifiers

--------------+-----------------------+-----------------------------------------
mpl_id | integer | not null default
nextval('public.mitpln_mpl_id_seq'::text)
mpl_date | date |
mpl_minr | integer | not null
mpl_tpl_name | character varying(20) |
mpl_feiertag | character varying(50) |
mpl_min | real |
mpl_saldo | real |
mpl_buch | boolean | not null default false
mpl_absaldo | real |
mpl_vhz | real |
dbrid | character varying | default nextval('db_id_seq'::text)
Indexes:
"mitpln_pkey" PRIMARY KEY, btree (mpl_id)
"mitpln_idindex" UNIQUE, btree (dbrid)
"xtt5126" UNIQUE, btree (mpl_date, mpl_minr)
"mitpln_yearmonth_dec" btree
(date_to_yearmonth_dec(mpl_date::timestamp with
out time zone))
"mpl_minr" btree (mpl_minr)
"mpl_minr_nobuch" btree (mpl_minr) WHERE NOT mpl_buch

CIMSOFT=# SELECT count(*) FROM mitpln;
count
-------
26330
(1 row)

CREATE OR REPLACE FUNCTION date_to_yearmonth_dec(TIMESTAMP) RETURNS
VARCHAR AS'
BEGIN
RETURN extract(year FROM $1) || extract(month FROM $1)-1;
END'LANGUAGE plpgsql IMMUTABLE;

Daniel

PS : thats a 2.4 GHZ P4 Server with 1 GB Ram and RAID - SCSI
(WIN2000, PG8.0.1)

In response to

Browse pgsql-performance by date

  From Date Subject
Next Message Manfred Koizar 2005-03-17 11:18:28 Re: multi-column index
Previous Message Christopher Kings-Lynne 2005-03-17 08:55:15 Re: multi-column index