On Tue, Nov 28, 2017 at 9:59 PM, Tom Lane <tgl@xxxxxxxxxxxxx> wrote: > Brian Crowell <brian@xxxxxxxxxx> writes: >> On Tue, Nov 28, 2017 at 12:38 PM, Tomas Vondra <tomas.vondra@xxxxxxxxxxxxxxx >>> wrote: >>> So what does the script actually do? Because psql certainly is not >>> running pl/pgsql procedures on it's own. We need to understand why >>> you're getting OOM in the first place - just inserts alone should not >>> cause failures like that. Please show us more detailed explanation of >>> what the load actually does, so that we can try reproducing it. > >> Perhaps the script is one giant insert statement? > > It's pretty clear from the memory map that the big space consumption > is inside a single invocation of a plpgsql function: > > SPI Proc: 2464408024 total in 279 blocks; 1672 free (1 chunks); 2464406352 used > PL/pgSQL function context: 537911352 total in 74 blocks; 2387536 free (4 chunks); 535523816 used > > So whatever's going on here, there's more to it than a giant client-issued > INSERT (or COPY), or for that matter a large number of small ones. What > would seem to be required is a many-megabyte-sized plpgsql function body > or DO block. > > Actually, the truly weird thing about that map is that the "PL/pgSQL > function context" seems to be a child of a "SPI Proc" context, whereas > it's entirely clear from the code that it ought to be a direct child of > TopMemoryContext. I have no idea how this state of affairs came to be, > and am interested to find out. > > regards, tom lane Yes I did generate 1 large DO block: DO $$ DECLARE thingid bigint; thingrec bigint; thingdataid bigint; BEGIN INSERT INTO thing (ltn,classification,machine,source,thgrec,flags,serial,type) VALUES ('T007336','THING',0,1025,7336,7,'XXX869977564',1) RETURNING id,thgrec INTO thingid,thingrec; INSERT INTO recnum_thing (recnum,thing_id) VALUES (thingrec,thingid); INSERT INTO thingstatus (thing_id,nrpts,rmks_cs,force_type_id,ftn_cs,force_code,arr_cs,mask,toi_state,plot_id,signa_cs,lastchange,des_cs,rig_cs,ownship,correlation,maxrpts,rtn_cs,ctc_cs,group_mask,dep_cs) VALUES (thingid,121,'{0,0,0,0}',440,0,23,0,0,0,'{23,-1,3803,3805,-1,-1,0,6}',0,1509459164,0,0,0,0,1000,0,0,0,0); INSERT INTO thinger (thing_id,spe_key,cse_unc,lat_spd,cov,dtg,lng,spd,ave_spd,cse,tol,nrpts,lat,alpha,sigma,spd_unc,lng_spd) VALUES (thingid,-1,0.0,-6.58197336634e-08,'{4.27624291532e-09,0.0,3.07802916488e-09,0.0,4.27624291532e-09,0.0,3.07802916488e-09,4.16110417234e-08,0.0,4.16110417234e-08}',1509459163,2.21596980095,0.000226273215958,1.0,0.0,0.10000000149,121,0.584555745125,10.0,4.23079740131e-08,0.0,-2.49999881907e-10); INSERT INTO thingdata (thing_id,category,db_num,xref,org_type,trademark,shortname,fcode,platform,callsign,type,orig_xref,shipclass,home_base,uic,service,di,lngfixed,hull,precision,alert,flag,besufx,name,mmsi,catcode,ntds,imo,pn_num,chxref,threat,sconum,latfixed,db_type,pif,echelon,jtn,quantity,overwrite) VALUES (thingid,'XXX','','','','','004403704','23','','','','','UNEQUATED','','','','',0.0,'','{0,0,0,0,0}','','KS','','UNKNOWN','004403704','','','','','','AFD','',0.0,3,'','',0,0,0) RETURNING id INTO thingdataid; INSERT INTO thingnum (thingdata_id,thgnum,state,dtg,cmd) VALUES (thingdataid,'013086',0,1502970401,'FOO'); <repeated for each thing> END $$; Should I limit the number of 'thing' inserts within a DO block or wrapping each 'thing' insert in it's own DO block?