Tom, Thank you very much for your suggestions. > -----Original Message----- > From: Tom Lane [mailto:tgl@xxxxxxxxxxxxx] > > Have you checked to make sure the query plans are reasonable? I've attached the main query and its explain plan. I can't find a way to improve it. Does it make any difference if it's executed from a stored procedure? Is there any difference between the SP's language (PL/pgSQL, PL/php, etc. It needs to make some other tiny things besides the query)? > You might want to try contrib/pgstattuple Thanks. I'll give it a try and report the results here. > absolutely critical to boost checkpoint_segments far enough How do I know how ofen checkpoints are done? I've modified the parameters: checkpoint_segments = 36 # it was 12 before checkpoint_timeout = 1000 checkpoint_warning = 300 # so, I'll get a warning if it's too frequent. commit_delay = 5000 commit_siblings = 2 > adjusting bgwriter and/or vacuum cost delay parameters I've used a moderate cost delay configuration to see how it responds (vacuum_cost_delay = 100 & vacuum_cost_limit = 200). Do you have any advice on how to configure the bgwriter? I have no clue about it and couldn't find anything clear. Also, I know an upgrade to 8.2 is always a good thing, but is there any change that could help this specific situation? Again, thank you very much for your answers (and, of course, everything you do in pgsql). Regards, Mauro.
SELECT Player.Title, Player.IdPlayer FROM Player INNER JOIN ActivePlayer ON ActivePlayer.IdPlayer = Player.IdPlayer INNER JOIN PlayerCategoryShow ON PlayerCategoryShow.IdCategory = 18 AND PlayerCategoryShow.IdPlayer = Player.IdPlayer WHERE IdLanguage = 'EN' AND Player.IdPlayer NOT IN (279) AND Player.CreditsAvailable ORDER BY RANDOM() LIMIT 8; Limit (cost=36760.49..36760.51 rows=8 width=25) (actual time=130.359..130.375 rows=8 loops=1) -> Sort (cost=36760.49..36763.90 rows=1364 width=25) (actual time=130.355..130.360 rows=8 loops=1) Sort Key: random() -> Hash Join (cost=36252.38..36689.47 rows=1364 width=25) (actual time=87.092..126.733 rows=963 loops=1) Hash Cond: ("outer".idplayer = "inner".idplayer) -> Seq Scan on activeplayer (cost=0.00..276.45 rows=19145 width=4) (actual time=0.014..20.865 rows=19163 loops=1) -> Hash (cost=36248.24..36248.24 rows=1654 width=29) (actual time=86.901..86.901 rows=1250 loops=1) -> Hash Join (cost=35685.70..36248.24 rows=1654 width=29) (actual time=58.835..84.643 rows=1250 loops=1) Hash Cond: ("outer".idplayer = "inner".idplayer) -> Bitmap Heap Scan on playercategoryshow (cost=54.96..493.96 rows=8560 width=4) (actual time=2.445..14.130 rows=8397 loops=1) Recheck Cond: (idcategory = 18) -> Bitmap Index Scan on ix_playercategoryshow (cost=0.00..54.96 rows=8560 width=0) (actual time=2.328..2.328 rows=8401 loops=1) Index Cond: (idcategory = 18) -> Hash (cost=35619.53..35619.53 rows=4484 width=25) (actual time=56.294..56.294 rows=4114 loops=1) -> Bitmap Heap Scan on player (cost=5296.33..35619.53 rows=4484 width=25) (actual time=12.943..49.075 rows=4114 loops=1) Recheck Cond: ((idlanguage)::text = 'EN'::text) Filter: ((idplayer <> 279) AND creditsavailable) -> Bitmap Index Scan on ix_player3 (cost=0.00..5296.33 rows=15809 width=0) (actual time=9.868..9.868 rows=16245 loops=1) Index Cond: ((idlanguage)::text = 'EN'::text Total runtime: 130.946 ms