473,465 Members | 1,395 Online
Bytes | Software Development & Data Engineering Community
Create Post

Home Posts Topics Members FAQ

Trigger to update records out of memory

On 7.4.2 I have a trigger that I want to update any existing boolean
values to false if a new one in that group is declare true by inserting
a new record or updating an existing record:

ohc=# CREATE OR REPLACE FUNCTION "public"."clear_common_groups" ()
RETURNS trigger AS'
ohc'# BEGIN
ohc'# IF NEW.common_area = ''t'' THEN
ohc'# UPDATE tblhudunits SET common_area = ''f'' WHERE
hud_building_id = NEW.hud_building_id;
ohc'# END IF;
ohc'# IF NEW.exterior_area = ''t'' THEN
ohc'# UPDATE tblhudunits SET exterior_area = ''f'' WHERE
hud_building_id = NEW.hud_building_id;
ohc'# END IF;
ohc'# RETURN NULL;
ohc'# END;
ohc'# 'LANGUAGE 'plpgsql' IMMUTABLE CALLED ON NULL INPUT SECURITY
INVOKER;
CREATE FUNCTION
ohc=# CREATE TRIGGER "new_common_area" BEFORE INSERT OR UPDATE
ohc-# ON "public"."tblhudunits" FOR EACH ROW
ohc-# EXECUTE PROCEDURE "public"."clear_common_groups"();
CREATE TRIGGER
ohc=# update tblhudunits set common_area = 't' where sort_order = 2;
ERROR: out of memory
DETAIL: Failed on request of size 1048576.

Can someone point out what I am obviously doing wrong?

--
Robert
---------------------------(end of broadcast)---------------------------
TIP 6: Have you searched our list archives?

http://archives.postgresql.org

Nov 23 '05 #1
6 2266
On Fri, 2004-06-18 at 13:17, Robert Fitzpatrick wrote:
ohc=# CREATE OR REPLACE FUNCTION "public"."clear_common_groups" ()
RETURNS trigger AS'
ohc'# BEGIN
ohc'# IF NEW.common_area = ''t'' THEN
ohc'# UPDATE tblhudunits SET common_area = ''f'' WHERE
hud_building_id = NEW.hud_building_id;
ohc'# END IF;
ohc'# IF NEW.exterior_area = ''t'' THEN
ohc'# UPDATE tblhudunits SET exterior_area = ''f'' WHERE
hud_building_id = NEW.hud_building_id;
ohc'# END IF;
ohc'# RETURN NULL;
ohc'# END;
ohc'# 'LANGUAGE 'plpgsql' IMMUTABLE CALLED ON NULL INPUT SECURITY
INVOKER;
CREATE FUNCTION
ohc=# CREATE TRIGGER "new_common_area" BEFORE INSERT OR UPDATE
ohc-# ON "public"."tblhudunits" FOR EACH ROW
ohc-# EXECUTE PROCEDURE "public"."clear_common_groups"();
CREATE TRIGGER
ohc=# update tblhudunits set common_area = 't' where sort_order = 2;
ERROR: out of memory
DETAIL: Failed on request of size 1048576.


After getting doing some NOTICEs, I find it I'm looping my update
funtion. But I change the TRIGGER to 'BEFORE INSERT' instead and now I
have a peculiar problem. The first time I ran the UPDATE query, I
receive an good response, ever since I receive 'INSERT 0 0'. But neither
time did the record get inserted.

ohc=# insert into tblhudunits (hud_building_id, sort_order, common_area)
values (21, 10, 't');
NOTICE: 21
INSERT 1304826 1
ohc=# insert into tblhudunits (hud_building_id, sort_order, common_area)
values (21, 10, 't');
NOTICE: 21
INSERT 0 0

Same 'INSERT 0 0' no matter what valid values I use. Can someone tell me
what it means to receive 'INSERT 0 0'?

--
Robert
---------------------------(end of broadcast)---------------------------
TIP 7: don't forget to increase your free space map settings

Nov 23 '05 #2
On Fri, 2004-06-18 at 13:17, Robert Fitzpatrick wrote:
ohc=# CREATE OR REPLACE FUNCTION "public"."clear_common_groups" ()
RETURNS trigger AS'
ohc'# BEGIN
ohc'# IF NEW.common_area = ''t'' THEN
ohc'# UPDATE tblhudunits SET common_area = ''f'' WHERE
hud_building_id = NEW.hud_building_id;
ohc'# END IF;
ohc'# IF NEW.exterior_area = ''t'' THEN
ohc'# UPDATE tblhudunits SET exterior_area = ''f'' WHERE
hud_building_id = NEW.hud_building_id;
ohc'# END IF;
ohc'# RETURN NULL;
ohc'# END;
ohc'# 'LANGUAGE 'plpgsql' IMMUTABLE CALLED ON NULL INPUT SECURITY
INVOKER;
CREATE FUNCTION
ohc=# CREATE TRIGGER "new_common_area" BEFORE INSERT OR UPDATE
ohc-# ON "public"."tblhudunits" FOR EACH ROW
ohc-# EXECUTE PROCEDURE "public"."clear_common_groups"();
CREATE TRIGGER
ohc=# update tblhudunits set common_area = 't' where sort_order = 2;
ERROR: out of memory
DETAIL: Failed on request of size 1048576.


After getting doing some NOTICEs, I find it I'm looping my update
funtion. But I change the TRIGGER to 'BEFORE INSERT' instead and now I
have a peculiar problem. The first time I ran the UPDATE query, I
receive an good response, ever since I receive 'INSERT 0 0'. But neither
time did the record get inserted.

ohc=# insert into tblhudunits (hud_building_id, sort_order, common_area)
values (21, 10, 't');
NOTICE: 21
INSERT 1304826 1
ohc=# insert into tblhudunits (hud_building_id, sort_order, common_area)
values (21, 10, 't');
NOTICE: 21
INSERT 0 0

Same 'INSERT 0 0' no matter what valid values I use. Can someone tell me
what it means to receive 'INSERT 0 0'?

--
Robert
---------------------------(end of broadcast)---------------------------
TIP 7: don't forget to increase your free space map settings

Nov 23 '05 #3
I think the IMMUTABLE might be your issue.

Robert Fitzpatrick wrote:
On Fri, 2004-06-18 at 13:17, Robert Fitzpatrick wrote:

ohc=# CREATE OR REPLACE FUNCTION "public"."clear_common_groups" ()
RETURNS trigger AS'
ohc'# BEGIN
ohc'# IF NEW.common_area = ''t'' THEN
ohc'# UPDATE tblhudunits SET common_area = ''f'' WHERE
hud_building_id = NEW.hud_building_id;
ohc'# END IF;
ohc'# IF NEW.exterior_area = ''t'' THEN
ohc'# UPDATE tblhudunits SET exterior_area = ''f'' WHERE
hud_building_id = NEW.hud_building_id;
ohc'# END IF;
ohc'# RETURN NULL;
ohc'# END;
ohc'# 'LANGUAGE 'plpgsql' IMMUTABLE CALLED ON NULL INPUT SECURITY
INVOKER;
CREATE FUNCTION
ohc=# CREATE TRIGGER "new_common_area" BEFORE INSERT OR UPDATE
ohc-# ON "public"."tblhudunits" FOR EACH ROW
ohc-# EXECUTE PROCEDURE "public"."clear_common_groups"();
CREATE TRIGGER
ohc=# update tblhudunits set common_area = 't' where sort_order = 2;
ERROR: out of memory
DETAIL: Failed on request of size 1048576.


After getting doing some NOTICEs, I find it I'm looping my update
funtion. But I change the TRIGGER to 'BEFORE INSERT' instead and now I
have a peculiar problem. The first time I ran the UPDATE query, I
receive an good response, ever since I receive 'INSERT 0 0'. But neither
time did the record get inserted.

ohc=# insert into tblhudunits (hud_building_id, sort_order, common_area)
values (21, 10, 't');
NOTICE: 21
INSERT 1304826 1
ohc=# insert into tblhudunits (hud_building_id, sort_order, common_area)
values (21, 10, 't');
NOTICE: 21
INSERT 0 0

Same 'INSERT 0 0' no matter what valid values I use. Can someone tell me
what it means to receive 'INSERT 0 0'?

---------------------------(end of broadcast)---------------------------
TIP 2: you can get off all lists at once with the unregister command
(send "unregister YourEmailAddressHere" to ma*******@postgresql.org)

Nov 23 '05 #4
I think the IMMUTABLE might be your issue.

Robert Fitzpatrick wrote:
On Fri, 2004-06-18 at 13:17, Robert Fitzpatrick wrote:

ohc=# CREATE OR REPLACE FUNCTION "public"."clear_common_groups" ()
RETURNS trigger AS'
ohc'# BEGIN
ohc'# IF NEW.common_area = ''t'' THEN
ohc'# UPDATE tblhudunits SET common_area = ''f'' WHERE
hud_building_id = NEW.hud_building_id;
ohc'# END IF;
ohc'# IF NEW.exterior_area = ''t'' THEN
ohc'# UPDATE tblhudunits SET exterior_area = ''f'' WHERE
hud_building_id = NEW.hud_building_id;
ohc'# END IF;
ohc'# RETURN NULL;
ohc'# END;
ohc'# 'LANGUAGE 'plpgsql' IMMUTABLE CALLED ON NULL INPUT SECURITY
INVOKER;
CREATE FUNCTION
ohc=# CREATE TRIGGER "new_common_area" BEFORE INSERT OR UPDATE
ohc-# ON "public"."tblhudunits" FOR EACH ROW
ohc-# EXECUTE PROCEDURE "public"."clear_common_groups"();
CREATE TRIGGER
ohc=# update tblhudunits set common_area = 't' where sort_order = 2;
ERROR: out of memory
DETAIL: Failed on request of size 1048576.


After getting doing some NOTICEs, I find it I'm looping my update
funtion. But I change the TRIGGER to 'BEFORE INSERT' instead and now I
have a peculiar problem. The first time I ran the UPDATE query, I
receive an good response, ever since I receive 'INSERT 0 0'. But neither
time did the record get inserted.

ohc=# insert into tblhudunits (hud_building_id, sort_order, common_area)
values (21, 10, 't');
NOTICE: 21
INSERT 1304826 1
ohc=# insert into tblhudunits (hud_building_id, sort_order, common_area)
values (21, 10, 't');
NOTICE: 21
INSERT 0 0

Same 'INSERT 0 0' no matter what valid values I use. Can someone tell me
what it means to receive 'INSERT 0 0'?

---------------------------(end of broadcast)---------------------------
TIP 2: you can get off all lists at once with the unregister command
(send "unregister YourEmailAddressHere" to ma*******@postgresql.org)

Nov 23 '05 #5
DeJuan Jackson <dj******@speedfc.com> writes:
I think the IMMUTABLE might be your issue.


Nah, the problem is that the trigger is recursive.
The UPDATEs it performs internally trigger the trigger again,
resulting in another UPDATE, resulting in another trigger call...
eventually you run out of memory.

AFAICT the UPDATEs are the hardest possible way to do things
anyhow. You're in a BEFORE trigger, you can just alter the NEW
record to alter what will be stored.

Finally, RETURN NULL is not what you want in a BEFORE trigger;
that disables actually doing anything. (In this case it fails
before you ever get that far :-()

In short the function ought to look more like

CREATE OR REPLACE FUNCTION clear_common_groups () RETURNS trigger AS'
BEGIN
IF NEW.common_area = ''t'' THEN
NEW.common_area = ''f'';
END IF;
IF NEW.exterior_area = ''t'' THEN
NEW.exterior_area = ''f'';
END IF;
RETURN NEW;
END;
' LANGUAGE 'plpgsql';

I agree that the IMMUTABLE and other decorations are useless though...

regards, tom lane

---------------------------(end of broadcast)---------------------------
TIP 6: Have you searched our list archives?

http://archives.postgresql.org

Nov 23 '05 #6
DeJuan Jackson <dj******@speedfc.com> writes:
I think the IMMUTABLE might be your issue.


Nah, the problem is that the trigger is recursive.
The UPDATEs it performs internally trigger the trigger again,
resulting in another UPDATE, resulting in another trigger call...
eventually you run out of memory.

AFAICT the UPDATEs are the hardest possible way to do things
anyhow. You're in a BEFORE trigger, you can just alter the NEW
record to alter what will be stored.

Finally, RETURN NULL is not what you want in a BEFORE trigger;
that disables actually doing anything. (In this case it fails
before you ever get that far :-()

In short the function ought to look more like

CREATE OR REPLACE FUNCTION clear_common_groups () RETURNS trigger AS'
BEGIN
IF NEW.common_area = ''t'' THEN
NEW.common_area = ''f'';
END IF;
IF NEW.exterior_area = ''t'' THEN
NEW.exterior_area = ''f'';
END IF;
RETURN NEW;
END;
' LANGUAGE 'plpgsql';

I agree that the IMMUTABLE and other decorations are useless though...

regards, tom lane

---------------------------(end of broadcast)---------------------------
TIP 6: Have you searched our list archives?

http://archives.postgresql.org

Nov 23 '05 #7

This thread has been closed and replies have been disabled. Please start a new discussion.

Similar topics

4
by: Steve Bishop | last post by:
I have an Insert, Update and delete trigger on a table that works fine. It records the changes into another table called tblTracking. tblTracking records the changes so they can be uploaded to...
1
by: shottarum | last post by:
I currently have 2 tables as follows: CREATE TABLE . ( mhan8 int, mhac02 varchar(5), mhmot varchar(5), mhupmj int )
9
by: Martin | last post by:
Hello, I'm new with triggers and I can not find any good example on how to do the following: I have two tables WO and PM with the following fields: WO.WONUM, VARCHAR(10) WO.PMNUM,...
33
by: coosa | last post by:
I have a table: ---------------------------------------------------- CREATE TABLE CATEGORY ( CATEGORY_ID INTEGER IDENTITY(1,1) NOT NULL, CATEGORY_NAME VARCHAR(40) NOT NULL,...
0
by: JohnO | last post by:
Thanks to Serge and MarkB for recent tips and suggestions. Ive rolled together a few stored procedures to assist with creating audit triggers automagically. Hope someone finds this as useful as...
2
by: D. Dante Lorenso | last post by:
I'm trying to build a table that will store a history of records by enumerating the records. I want the newest record to always be number ZERO, so I created a trigger on my table to handle the...
0
by: Robert Fitzpatrick | last post by:
On 7.4.2 I have a trigger that I want to update any existing boolean values to false if a new one in that group is declare true by inserting a new record or updating an existing record: ohc=#...
0
by: istruttorenuoto | last post by:
Hi, I have a problem for a DB2 trigger that take records from a table and put them into another one. I need to do a choice when i copy from a table to another. I made my trigger and it works...
4
by: rcamarda | last post by:
I have a UDF that cleans a field of control characters and I use it like this select dbo.udf_CleanAlphaNum(Address1) as Address1 from Leads It works great. I use it to clean several fields...
0
by: Hystou | last post by:
There are some requirements for setting up RAID: 1. The motherboard and BIOS support RAID configuration. 2. The motherboard has 2 or more available SATA protocol SSD/HDD slots (including MSATA, M.2...
0
marktang
by: marktang | last post by:
ONU (Optical Network Unit) is one of the key components for providing high-speed Internet services. Its primary function is to act as an endpoint device located at the user's premises. However,...
0
by: Hystou | last post by:
Most computers default to English, but sometimes we require a different language, especially when relocating. Forgot to request a specific language before your computer shipped? No problem! You can...
0
Oralloy
by: Oralloy | last post by:
Hello folks, I am unable to find appropriate documentation on the type promotion of bit-fields when using the generalised comparison operator "<=>". The problem is that using the GNU compilers,...
0
jinu1996
by: jinu1996 | last post by:
In today's digital age, having a compelling online presence is paramount for businesses aiming to thrive in a competitive landscape. At the heart of this digital strategy lies an intricately woven...
1
by: Hystou | last post by:
Overview: Windows 11 and 10 have less user interface control over operating system update behaviour than previous versions of Windows. In Windows 11 and 10, there is no way to turn off the Windows...
0
tracyyun
by: tracyyun | last post by:
Dear forum friends, With the development of smart home technology, a variety of wireless communication protocols have appeared on the market, such as Zigbee, Z-Wave, Wi-Fi, Bluetooth, etc. Each...
0
agi2029
by: agi2029 | last post by:
Let's talk about the concept of autonomous AI software engineers and no-code agents. These AIs are designed to manage the entire lifecycle of a software development project—planning, coding, testing,...
0
by: TSSRALBI | last post by:
Hello I'm a network technician in training and I need your help. I am currently learning how to create and manage the different types of VPNs and I have a question about LAN-to-LAN VPNs. The...

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.