Re: ORDER BY costs

Поиск
Список
Период
Сортировка
От Carlos Benkendorf
Тема Re: ORDER BY costs
Дата
Msg-id 20051222003501.98879.qmail@web35513.mail.mud.yahoo.com
обсуждение исходный текст
Ответ на Re: ORDER BY costs  (Tom Lane <tgl@sss.pgh.pa.us>)
Список pgsql-performance
I restored the table in another database and repeated the analyze again with original column definitions (numeric):
 
With order by:
Sort  (cost=212634.30..213032.73 rows=159374 width=897) (actual time=9286.817..9865.030 rows=167710 loops=1)
   Sort Key: anocalc, cadastro, codvencto, parcela
   ->  Index Scan using pk_arript, pk_arript, pk_arript, pk_arript on arript  (cost=0.00..126604.64 rows=159374 width=897) (actual time=0.152..1062.664 rows=167710 loops=1)
         Index Cond: (((anocalc = 2005::numeric) AND (cadastro = 19::numeric) AND (codvencto = 0::numeric) AND (parcela >= 0::numeric)) OR ((anocalc = 2005::numeric) AND (cadastro = 19::numeric) AND (codvencto > 0::numeric)) OR ((anocalc = 2005::numeric) AND (cadastro > 19::numeric)) OR (anocalc > 2005::numeric))
 Total runtime: 10086.884 ms
(5 rows)
 
Without order by:
 Index Scan using pk_arript, pk_arript, pk_arript, pk_arript on arript  (cost=0.00..126604.64 rows=159374 width=897) (actual time=0.154..809.566 rows=167710 loops=1)
   Index Cond: (((anocalc = 2005::numeric) AND (cadastro = 19::numeric) AND (codvencto = 0::numeric) AND (parcela >= 0::numeric)) OR ((anocalc = 2005::numeric) AND (cadastro = 19::numeric) AND (codvencto > 0::numeric)) OR ((anocalc = 2005::numeric) AND (cadastro > 19::numeric)) OR (anocalc > 2005::numeric))
 Total runtime: 894.218 ms
(3 rows)


Then I recreated the table and changed the primary key column type definitions to smallint, integer and bigint.
 
CREATE TABLE arript (
    anocalc smallint     NOT NULL,
    cadastro integer      NOT NULL,
    codvencto smallint     NOT NULL,
    parcela smallint     NOT NULL,
    inscimob character varying(18) NOT NULL,
    codvencto2 smallint     NOT NULL,
    parcela2 smallint     NOT NULL,
    codpropr bigint        NOT NULL,
    dtaven integer      NOT NULL,
    anocalc2 smallint,
    dtabase integer,
    vvt numeric(14,2),
    vvp numeric(14,2),
...
...
 
Now the new analyze:
 
With order by:
 Sort  (cost=180430.98..180775.10 rows=137649 width=826) (actual time=4461.524..5000.707 rows=167710 loops=1)
   Sort Key: anocalc, cadastro, codvencto, parcela
   ->&n bsp; Index Scan using pk_arript, pk_arript, pk_arript, pk_arript on arript  (cost=0.00..111126.93 rows=137649 width=826) (actual time=0.142..763.255 rows=167710 loops=1)
         Index Cond: (((anocalc = 2005) AND (cadastro = 19) AND (codvencto = 0) AND (parcela >= 0)) OR ((anocalc = 2005) AND (cadastro = 19) AND (codvencto > 0)) OR ((anocalc = 2005) AND (cadastro > 19)) OR (anocalc > 2005))
 Total runtime: 5222.729 ms
(5 rows)
 
 
Without order by:
 Index Scan using pk_arript, pk_arript, pk_arript, pk_arript on arript  (cost=0.00..111126.93 rows=137649 width=826) (actual time=0.135..505.250 rows=167710 loops=1)
   Index Cond: (((anocalc = 2005) AND (cadastro = 19) AND (codvencto = 0) AND (parcela >= 0)) OR ((anocalc = 2005) AND (cadastro = 19) AND (codvencto > 0)) OR ((anocalc = 2005) AND (cadastro > 19)) OR (anocalc > 2005))
 Total runtime: 589.528 ms
(3 rows)
Total runtime summary:
Primary key columns defined with integer/smallint/bigint and select with order by: 5222.729 ms
Primary key columns defined with integer/smallint/bigint and select without order by: 589.528 ms
Primary key columns defined with numeric and select with order by: 10086.884 ms
Primary key columns defined with numeric and select without order by: 894.218 ms
 
Using order by and integer/smallint/bigint (5222.729) is almost half total runtime of select over numeric columns (10086.884) but is still 6 x more from the numbers of the original select (without order by and number columns=894.218).
 
Is there something more that could be done? Planner cost constants?
 
Thanks very much in advance!< /DIV>
 
Benkendorf
 
 


Yahoo! doce lar. Faça do Yahoo! sua homepage.

В списке pgsql-performance по дате отправления:

Предыдущее
От: William Yu
Дата:
Сообщение: Re: What's the best hardver for PostgreSQL 8.1?
Следующее
От: "Steinar H. Gunderson"
Дата:
Сообщение: Re: Speed of different procedural language