Portál AbcLinuxu, 12. května 2025 17:14
SET transaction_memory_limit=500M;
skor by som povedal, ze v tej funkcii bude memory-leak.
CREATE OR REPLACE FUNCTION icv_objects2(integer,integer) RETURNS void AS $BODY$ DECLARE rec RECORD; BEGIN FOR rec IN SELECT * FROM md_metadata_old WHERE id_metadata::integer BETWEEN $1 AND $2 LOOP RAISE NOTICE 'Adding values for metadata %',rec.id_metadata; IF rec.id_metadatagroup IS NOT NULL THEN BEGIN EXECUTE 'INSERT INTO md_metadata(fileidentifier,parentidentifier,identificationinfo) VALUES('||rec.id_metadata::integer||', '||rec.id_metadatagroup::integer||', '||rec.id_metadata::integer||')'; EXCEPTION WHEN foreign_key_violation THEN EXECUTE 'INSERT INTO md_metadata(fileidentifier,parentidentifier,identificationinfo) VALUES('||rec.id_metadata::integer||', '||rec.id_metadata::integer||', '||rec.id_metadata::integer||')'; END; END IF; END LOOP; END; $BODY$PostgreSQL 8.1.0
ak ma pamat neklame, problem je ten, ze select taha vsetky data do pamate. vyskusajte implementovat nasledovny pseudokod (bohuzival plpgsql neovladam/nepouzivam) :
"declare cursor nejake_meno for select * from md_metadata_old;" while row = "fetch from nejake_meno" insert into ... end
CREATE OR REPLACE FUNCTION icv_objects3() RETURNS void AS $BODY$ DECLARE row md_metadata_old%ROWTYPE; curs REFCURSOR; BEGIN OPEn curs FOR SELECT * FROM md_metadata_old; FETCH curs INTO row; WHILE FOUND LOOP RAISE NOTICE 'Adding values for metadata %',row.id_metadata; IF row.id_metadatagroup IS NOT NULL THEN BEGIN EXECUTE 'INSERT INTO md_metadata_test(fileidentifier,parentidentifier,identificationinfo) VALUES('||row.id_metadata::integer||', '||row.id_metadatagroup::integer||', '||row.id_metadata::integer||')'; EXCEPTION WHEN foreign_key_violation THEN END; END IF; FETCH curs INTO row; END LOOP; CLOSE curs; END; $BODY$ LANGUAGE 'plpgsql' VOLATILE;http://www.postgresql.org/docs/8.1/interactive/plpgsql-cursors.html#PLPGSQL-CURSOR-DECLARATIONS To by bylo, dekuji barney! Nicmene, zpet k puvodni otazce, nemohu nejak omezit prostredky pro jednotlive query? Pokud takovou fci nekdo spusti treba na sdilenem hostingu? Asi kazdy namitne ze tam potom nema co pohledavat, nicmene vypadek hrozi, nebo dokonce nekonzistence dat, pokud by postmaster mel omezeni v OS.
Tiskni
Sdílej:
ISSN 1214-1267, (c) 1999-2007 Stickfish s.r.o.