cpu_tuple_cost - Mailing list pgsql-performance

From Daniel Schuchardt
Subject cpu_tuple_cost
Date
Msg-id d0s9o7$1da1$1@news.hub.org
Whole thread Raw
Responses Re: cpu_tuple_cost
List pgsql-performance
Hi List,

i have a query plan who is bad with standard cpu_tuple_costs and good if
I raise cpu_tuple_costs. Is it is a good practice to raise them if i
want to force postgres to use indexes more often? Or is it is better to
disable sequence scans?

CIMSOFT=# ANALYSE mitpln;
ANALYZE

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

--------------------------------------------------------------------------------
  Seq Scan on mitpln  (cost=0.00..1411.85 rows=2050 width=69) (actual
time=562.000..1203.000 rows=1269 loops=1)
    Filter: ((date_to_yearmonth_dec((mpl_date)::timestamp without time
zone))::text = '20050'::text)
  Total runtime: 1203.000 ms
(3 rows)

CIMSOFT=# SET cpu_tuple_cost = 0.07;
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..2962.86
rows=2050width=69) (actual time=0.000..0.000 rows=1269 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))


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

pgsql-performance by date:

Previous
From: Daniel Schuchardt
Date:
Subject: Re: cpu_tuple_cost
Next
From: "Michael McFarland"
Date:
Subject: Re: adding 'limit' leads to very slow query