Thread: Trigger to update records out of memory

Trigger to update records out of memory

From
Robert Fitzpatrick
Date:
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


Re: Trigger to update records out of memory

From
Robert Fitzpatrick
Date:
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


Re: Trigger to update records out of memory

From
DeJuan Jackson
Date:
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'?
>
>
>


Re: Trigger to update records out of memory

From
Tom Lane
Date:
DeJuan Jackson <djackson@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