Thread: join problems: FATAL 1: palloc failure: memory exhausted
Hi, Below is an example of my query, which returns no plan and produces FATAL 1: palloc failure: memory exhausted while postgres 'eats' almost 113 Mb of RAM. This happens with pgsql 6.3.2+patches plus latest Vadim's one on Linux 2.0.35 libc5. Sorry for variable names :-) I remember discussion prior 6.3.2 about optimization of join and tried various -f options but this doesn't helps. When I run postmaster in debug mode I noticed some complains about geqo config file doesn't exists but not sure if this important. When I tried explain with less joins I got very bad plans with no indices used. Tables are not big - about 1000 records - just a classificators (2 columns) and only work_flats has 31 columns. Most columns have int2, int4 types. So database looks very simple and I didn't expect any problem. Of course there are a bunch of indices and I did vacuum before query. Currently I have to run a bunch of queries and do joins by hand (using perl) :-( Does development version 6.4 has some improvements ? I tried latest snapshot but couldn't run because of problem with initdb and missing anonymous cvs account. Regards, Oleg flats=> \i test.sql explain select a.ROOMS, b.STATION, a.STREET, a.HOUSE_NO, a.FLAT_NO, float8(a.PRICE)/1000.0, a.DO_METRO, c.SPOSOB_SH, a.FLOOR, e.HOUSE_TYPE_SHORT, a.HOUSE_FLOORS, float8(a.ALL_SQR)/100.0, float8(a.LIVE_SQR)/100.0, float8(a.KITCHEN)/100.0, f.SANUZEL_SHORT, a.SANUZEL_NO, a.BALKON, a.LODZHIA, a.HAVE_PHONE, a.HAVE_LIFT, a.HAVE_MUSOR, g.POL_SHORT, h.SOST_SHORT, i.STATUS_SHORT, a.COMMENT from WORK_FLATS a, METRO_STATIONS b, SPOSOB c, SERIALS d, HOUSE_TYPE e, SANUZELS f, POLS g, SOSTS h, STATUS i where b.STATION_ID = a.METRO_ID and c.SPOSOB_ID = a.DO_METRO_ID and a.SERIAL_ID = d.SERIAL_ID and d.HOUSE_TYPE_ID = e.HOUSE_TYPE_ID and f.SANUZEL_ID = a.SANUZEL and g.POL_ID = a.POL_ID and h.SOST_ID = a.SOST_ID and i.STATUS_ID = a.STATUS_ID and a.rooms = 1; FATAL 1: palloc failure: memory exhausted _____________________________________________________________ Oleg Bartunov, sci.researcher, hostmaster of AstroNet, Sternberg Astronomical Institute, Moscow University (Russia) Internet: oleg@sai.msu.su, http://www.sai.msu.su/~megera/ phone: +007(095)939-16-83, +007(095)939-23-83
Oleg Bartunov wrote: > > explain select > a.ROOMS, b.STATION, a.STREET, a.HOUSE_NO, a.FLAT_NO, > float8(a.PRICE)/1000.0, a.DO_METRO, c.SPOSOB_SH, a.FLOOR, > e.HOUSE_TYPE_SHORT, a.HOUSE_FLOORS, float8(a.ALL_SQR)/100.0, > float8(a.LIVE_SQR)/100.0, float8(a.KITCHEN)/100.0, f.SANUZEL_SHORT, > a.SANUZEL_NO, a.BALKON, a.LODZHIA, a.HAVE_PHONE, a.HAVE_LIFT, > a.HAVE_MUSOR, g.POL_SHORT, h.SOST_SHORT, i.STATUS_SHORT, a.COMMENT > from WORK_FLATS a, METRO_STATIONS b, SPOSOB c, SERIALS d, > HOUSE_TYPE e, SANUZELS f, POLS g, SOSTS h, STATUS i > where b.STATION_ID = a.METRO_ID and c.SPOSOB_ID = a.DO_METRO_ID and > a.SERIAL_ID = d.SERIAL_ID and d.HOUSE_TYPE_ID = e.HOUSE_TYPE_ID and > f.SANUZEL_ID = a.SANUZEL and g.POL_ID = a.POL_ID and > h.SOST_ID = a.SOST_ID and i.STATUS_ID = a.STATUS_ID and > a.rooms = 1; > FATAL 1: palloc failure: memory exhausted Now please try the same after SET GEQO TO 'off'; Vadim
Try changing the geqo parameters with SET GEQO and see if that helps. > Hi, > > Below is an example of my query, which returns no plan and produces > FATAL 1: palloc failure: memory exhausted while postgres 'eats' > almost 113 Mb of RAM. This happens with pgsql 6.3.2+patches plus latest > Vadim's one on Linux 2.0.35 libc5. Sorry for variable names :-) > I remember discussion prior 6.3.2 about optimization of join and > tried various -f options but this doesn't helps. > When I run postmaster in debug mode I noticed some complains about > geqo config file doesn't exists but not sure if this important. > When I tried explain with less joins I got very bad plans with no > indices used. Tables are not big - about 1000 records - just > a classificators (2 columns) and only work_flats has 31 columns. > Most columns have int2, int4 types. So database looks very simple and > I didn't expect any problem. > Of course there are a bunch of indices and I did vacuum before query. > Currently I have to run a bunch of queries and do joins > by hand (using perl) :-( > > Does development version 6.4 has some improvements ? I tried > latest snapshot but couldn't run because of problem with initdb and > missing anonymous cvs account. > > Regards, > > Oleg > > flats=> \i test.sql > explain select > a.ROOMS, b.STATION, a.STREET, a.HOUSE_NO, a.FLAT_NO, > float8(a.PRICE)/1000.0, a.DO_METRO, c.SPOSOB_SH, a.FLOOR, > e.HOUSE_TYPE_SHORT, a.HOUSE_FLOORS, float8(a.ALL_SQR)/100.0, > float8(a.LIVE_SQR)/100.0, float8(a.KITCHEN)/100.0, f.SANUZEL_SHORT, > a.SANUZEL_NO, a.BALKON, a.LODZHIA, a.HAVE_PHONE, a.HAVE_LIFT, > a.HAVE_MUSOR, g.POL_SHORT, h.SOST_SHORT, i.STATUS_SHORT, a.COMMENT > from WORK_FLATS a, METRO_STATIONS b, SPOSOB c, SERIALS d, > HOUSE_TYPE e, SANUZELS f, POLS g, SOSTS h, STATUS i > where b.STATION_ID = a.METRO_ID and c.SPOSOB_ID = a.DO_METRO_ID and > a.SERIAL_ID = d.SERIAL_ID and d.HOUSE_TYPE_ID = e.HOUSE_TYPE_ID and > f.SANUZEL_ID = a.SANUZEL and g.POL_ID = a.POL_ID and > h.SOST_ID = a.SOST_ID and i.STATUS_ID = a.STATUS_ID and > a.rooms = 1; > FATAL 1: palloc failure: memory exhausted > > > _____________________________________________________________ > Oleg Bartunov, sci.researcher, hostmaster of AstroNet, > Sternberg Astronomical Institute, Moscow University (Russia) > Internet: oleg@sai.msu.su, http://www.sai.msu.su/~megera/ > phone: +007(095)939-16-83, +007(095)939-23-83 > > > -- Bruce Momjian | 830 Blythe Avenue maillist@candle.pha.pa.us | Drexel Hill, Pennsylvania 19026 + If your life is a hard drive, | (610) 353-9879(w) + Christ can be your backup. | (610) 853-3000(h)
> Oleg Bartunov wrote: > > > > explain select > > a.ROOMS, b.STATION, a.STREET, a.HOUSE_NO, a.FLAT_NO, > > float8(a.PRICE)/1000.0, a.DO_METRO, c.SPOSOB_SH, a.FLOOR, > > e.HOUSE_TYPE_SHORT, a.HOUSE_FLOORS, float8(a.ALL_SQR)/100.0, > > float8(a.LIVE_SQR)/100.0, float8(a.KITCHEN)/100.0, f.SANUZEL_SHORT, > > a.SANUZEL_NO, a.BALKON, a.LODZHIA, a.HAVE_PHONE, a.HAVE_LIFT, > > a.HAVE_MUSOR, g.POL_SHORT, h.SOST_SHORT, i.STATUS_SHORT, a.COMMENT > > from WORK_FLATS a, METRO_STATIONS b, SPOSOB c, SERIALS d, > > HOUSE_TYPE e, SANUZELS f, POLS g, SOSTS h, STATUS i > > where b.STATION_ID = a.METRO_ID and c.SPOSOB_ID = a.DO_METRO_ID and > > a.SERIAL_ID = d.SERIAL_ID and d.HOUSE_TYPE_ID = e.HOUSE_TYPE_ID and > > f.SANUZEL_ID = a.SANUZEL and g.POL_ID = a.POL_ID and > > h.SOST_ID = a.SOST_ID and i.STATUS_ID = a.STATUS_ID and > > a.rooms = 1; > > FATAL 1: palloc failure: memory exhausted > > Now please try the same after > > SET GEQO TO 'off'; If that fixes it, this is the second recent case where geqo was consuming too much memory. -- Bruce Momjian | 830 Blythe Avenue maillist@candle.pha.pa.us | Drexel Hill, Pennsylvania 19026 + If your life is a hard drive, | (610) 353-9879(w) + Christ can be your backup. | (610) 853-3000(h)
OK, flats=> set GEQO TO 'off'; SET VARIABLE flats=> \i test.sql explain select a.ROOMS, b.STATION, a.STREET, a.HOUSE_NO, a.FLAT_NO, float8(a.PRICE)/1000.0, a.DO_METRO, c.SPOSOB_SH, a.FLOOR, e.HOUSE_TYPE_SHORT, a.HOUSE_FLOORS, float8(a.ALL_SQR)/100.0, float8(a.LIVE_SQR)/100.0, float8(a.KITCHEN)/100.0, f.SANUZEL_SHORT, a.SANUZEL_NO, a.BALKON, a.LODZHIA, a.HAVE_PHONE, a.HAVE_LIFT, a.HAVE_MUSOR, g.POL_SHORT, h.SOST_SHORT, i.STATUS_SHORT, a.COMMENT from WORK_FLATS a, METRO_STATIONS b, SPOSOB c, SERIALS d, HOUSE_TYPE e, SANUZELS f, POLS g, SOSTS h, STATUS i where b.STATION_ID = a.METRO_ID and c.SPOSOB_ID = a.DO_METRO_ID and a.SERIAL_ID = d.SERIAL_ID and d.HOUSE_TYPE_ID = e.HOUSE_TYPE_ID and f.SANUZEL_ID = a.SANUZEL and g.POL_ID = a.POL_ID and h.SOST_ID = a.SOST_ID and i.STATUS_ID = a.STATUS_ID and a.rooms = 1; waiting .... waiting .... gave up after 20 minutes :-( It seems setting GEQO to 'off' doesn't helps. It's on P200, 64 Mb RAM, SCSI ... 6:23am up 10 days, 15:14, 12 users, load average: 1.29, 1.04, 0.65 89 processes: 86 sleeping, 3 running, 0 zombie, 0 stopped CPU states: 50.1% user, 2.7% system, 0.0% nice, 47.2% idle Mem: 62988K av, 62348K used, 640K free, 6624K shrd, 180K buff Swap: 130748K av, 94956K used, 35792K free 4296K cached PID USER PRI NI SIZE RSS SHARE STAT LIB %CPU %MEM TIME COMMAND 22970 postgres 12 0 94160 47M 260 R 0 50.9 77.7 13:41 postgres Vadim, I can send you about 50 Kb compressed pg_dump of this db, if you like to see yourself. Oleg On Fri, 31 Jul 1998, Vadim Mikheev wrote: > Date: Fri, 31 Jul 1998 08:41:00 +0800 > From: Vadim Mikheev <vadim@krs.ru> > To: Oleg Bartunov <oleg@sai.msu.su> > Cc: hackers@postgreSQL.org > Subject: Re: [HACKERS] join problems: FATAL 1: palloc failure: memory exhausted > > Oleg Bartunov wrote: > > > > explain select > > a.ROOMS, b.STATION, a.STREET, a.HOUSE_NO, a.FLAT_NO, > > float8(a.PRICE)/1000.0, a.DO_METRO, c.SPOSOB_SH, a.FLOOR, > > e.HOUSE_TYPE_SHORT, a.HOUSE_FLOORS, float8(a.ALL_SQR)/100.0, > > float8(a.LIVE_SQR)/100.0, float8(a.KITCHEN)/100.0, f.SANUZEL_SHORT, > > a.SANUZEL_NO, a.BALKON, a.LODZHIA, a.HAVE_PHONE, a.HAVE_LIFT, > > a.HAVE_MUSOR, g.POL_SHORT, h.SOST_SHORT, i.STATUS_SHORT, a.COMMENT > > from WORK_FLATS a, METRO_STATIONS b, SPOSOB c, SERIALS d, > > HOUSE_TYPE e, SANUZELS f, POLS g, SOSTS h, STATUS i > > where b.STATION_ID = a.METRO_ID and c.SPOSOB_ID = a.DO_METRO_ID and > > a.SERIAL_ID = d.SERIAL_ID and d.HOUSE_TYPE_ID = e.HOUSE_TYPE_ID and > > f.SANUZEL_ID = a.SANUZEL and g.POL_ID = a.POL_ID and > > h.SOST_ID = a.SOST_ID and i.STATUS_ID = a.STATUS_ID and > > a.rooms = 1; > > FATAL 1: palloc failure: memory exhausted > > Now please try the same after > > SET GEQO TO 'off'; > > Vadim > _____________________________________________________________ Oleg Bartunov, sci.researcher, hostmaster of AstroNet, Sternberg Astronomical Institute, Moscow University (Russia) Internet: oleg@sai.msu.su, http://www.sai.msu.su/~megera/ phone: +007(095)939-16-83, +007(095)939-23-83
Oleg Bartunov wrote: > > Vadim, I can send you about 50 Kb compressed pg_dump of this db, > if you like to see yourself. Ok, send it. Vadim