Re: Why query plan is different? - Mailing list pgsql-performance
From | Andrzej Zawadzki |
---|---|
Subject | Re: Why query plan is different? |
Date | |
Msg-id | 8aa28a9c-95c1-a8bb-e542-e7e4fd499c27@gmail.com Whole thread Raw |
In response to | Why query plan is different? (Andrzej Zawadzki <zawadaa@wp.pl>) |
Responses |
Re: Why query plan is different?
|
List | pgsql-performance |
<div class="moz-cite-prefix">On 10.10.2016 17:31, Andrzej Zawadzki wrote:<br /></div><blockquote cite="mid:bb1d234e-62ee-70e8-44ef-9b0919ec1268@wp.pl"type="cite"> Hi,<br /> Today, I noticed strange situation:<br /><br/> The same query run on different servers has very different plan:<br /><br /> Q: SELECT b.* FROM kredytob b WHEREpesel = '22222222222' ORDER BY b.id DESC LIMIT 1 <br /><br /> Slow plan:<br /><br /> "Limit (cost=0.43..28712.33 rows=1width=4) (actual time=2574.041..2574.044 rows=1 loops=1)"<br /> " Output: id"<br /> " Buffers: shared hit=316132read=110001"<br /> " -> Index Scan Backward using kredytob_pkey on public.kredytob b (cost=0.43..3244444.80rows=113 width=4) (actual time=2574.034..2574.034 rows=1 loops=1)"<br /> " Output: id"<br />" Filter: (b.pesel = '22222222222'::bpchar)"<br /> " Rows Removed by Filter: 433609"<br /> " Buffers:shared hit=316132 read=110001"<br /> "Planning time: 0.414 ms"<br /> "Execution time: 2574.139 ms"<br /><br /><br/> Fast plan:<br /> "Limit (cost=115240.66..115240.66 rows=1 width=4) (actual time=463.275..463.276 rows=1 loops=1)"<br/> " Output: id"<br /> " Buffers: shared hit=14661 read=4576"<br /> " -> Sort (cost=115240.66..115240.94rows=112 width=4) (actual time=463.271..463.271 rows=1 loops=1)"<br /> " Output: id"<br/> " Sort Key: b.id DESC"<br /> " Sort Method: top-N heapsort Memory: 25kB"<br /> " Buffers:shared hit=14661 read=4576"<br /> " -> Index Scan using kredytob_pesel_typkred_opclass_idx on public.kredytobb (cost=0.43..115240.10 rows=112 width=4) (actual time=311.347..463.183 rows=5 loops=1)"<br /> " Output: id"<br /> " Index Cond: (b.pesel = '22222222222'::bpchar)"<br /> " Buffers:shared hit=14661 read=4576"<br /> "Planning time: 0.383 ms"<br /> "Execution time: 463.324 ms"<br /><br /> Data isalmost equal - "slow" has a few more rows in table. ("Fast" is a copy from 1 am today).<br /> Why runtime is slower?<br/></blockquote><br /> I made another INDEX, without opclass:<br /><br /> CREATE INDEX kredytob_pesel_typkred_idx<br/> ON public.kredytob<br /> USING btree<br /> (pesel COLLATE pg_catalog."default", typkred);<br/><br /> after that: analyze kredytob;<br /><br /> And now:<br /> "Limit (cost=333.31..333.31 rows=1 width=4)(actual time=0.100..0.102 rows=1 loops=1)"<br /> " Output: id"<br /> " Buffers: shared hit=8"<br /> " -> Sort (cost=333.31..333.59 rows=114 width=4) (actual time=0.095..0.095 rows=1 loops=1)"<br /> " Output: id"<br /> " Sort Key: b.id DESC"<br /> " Sort Method: top-N heapsort Memory: 25kB"<br /> " Buffers: shared hit=8"<br/> " -> Index Scan using kredytob_pesel_typkred_idx on public.kredytob b (cost=0.43..332.74 rows=114width=4) (actual time=0.046..0.065 rows=5 loops=1)"<br /> " Output: id"<br /> " Index Cond:(b.pesel = '22222222222'::bpchar)"<br /> " Buffers: shared hit=8"<br /> "Planning time: 0.438 ms"<br />"Execution time: 0.154 ms"<br /><br /> So, what is a reason that "SLOW" server doesn't like opclass index?<br /><br />-- <br /> Andrzej<br />
pgsql-performance by date: