472,378 Members | 1,219 Online
Bytes | Software Development & Data Engineering Community
Post Job

Home Posts Topics Members FAQ

Join Bytes to post your question to a community of 472,378 software developers and data experts.

parameter in trigger function

Hello everyone,

Several columns in sereval tables in my DB should always be lowercase.
I now have a simple function:

create or replace function code_lower() returns trigger as '
begin
NEW.code := lower(NEW.code);
return NEW;
end'
language 'plpgsql';

which I call with a trigger like this:

create trigger my_trigger
before insert or update on my_table
execute procedure code_lower();

This will successfully lower() a field named 'code' in the table
'mytable' or any other table to which I point it. But some of my tables
have fields which should be lower()ed that have names other than
'code'. Writing a function for every of these field seems stupid, so I
tried to give the trigger arguments. Code like this

NEW.$1 := lower(NEW.$1)

won't work, all I get is error messages :-( The doc says this should be
OK (http://www.postgresql.org/docs/7.3/static/triggers.html) but Google
mostly says the opposite. Is this possible at all? How do I read the
TriggerData structure from whithin a pl/pgsql function?

TIA!

---------------------------(end of broadcast)---------------------------
TIP 3: if posting/reading through Usenet, please send an appropriate
subscribe-nomail command to ma*******@postgresql.org so that your
message can get through to the mailing list cleanly

Nov 11 '05 #1
2 6087
"Jules Alberts" <ju***********@arbodienst-limburg.nl> writes:
Code like this
NEW.$1 := lower(NEW.$1)
won't work, all I get is error messages :-(
Can't do that in plpgsql; it does not like run-time specification of
table or field names. You could try using EXECUTE but I doubt that
will work either for an assignment to NEW.

I'd suggest using pltcl, which is more amenable to run-time
determination of field names.
mostly says the opposite. Is this possible at all? How do I read the
TriggerData structure from whithin a pl/pgsql function?


You are looking for TG_ARGV[], though this is not your biggest
problem...

regards, tom lane

---------------------------(end of broadcast)---------------------------
TIP 5: Have you checked our extensive FAQ?

http://www.postgresql.org/docs/faqs/FAQ.html

Nov 11 '05 #2
Jules Alberts wrote:
Hello everyone,

Several columns in sereval tables in my DB should always be lowercase.
I now have a simple function:

create or replace function code_lower() returns trigger as '
begin
NEW.code := lower(NEW.code);
return NEW;
end'
language 'plpgsql';

which I call with a trigger like this:

create trigger my_trigger
before insert or update on my_table
execute procedure code_lower();

This will successfully lower() a field named 'code' in the table
'mytable' or any other table to which I point it. But some of my tables
have fields which should be lower()ed that have names other than
'code'. Writing a function for every of these field seems stupid, so I
tried to give the trigger arguments. Code like this

NEW.$1 := lower(NEW.$1)

won't work, all I get is error messages :-( The doc says this should be
OK (http://www.postgresql.org/docs/7.3/static/triggers.html) but Google
mostly says the opposite. Is this possible at all? How do I read the
TriggerData structure from whithin a pl/pgsql function?


It might seem stupid on the first look, but let's look again. PL/pgSQL
is a language that makes heavy use of cached query plans. Let's assume
your sample function above is triggered on it's first call in a session
for a table where "code" is an attribute of type "text". It will prepare
an SPI plan with the query "SELECT lower($1)" and tell the parser and
planner that the parameter $1 is of type "text". This plan is saved and
never touched again during the lifetime of your connection.

Now whenever your trigger function is called, it will put NEW.code into
a Datum array and call SPI_execp() for the above prepared plan. If you
now install the same trigger function on a table where "code" is of type
"name", this will not work because of a parameter type mismatch.

So it's even better not only to create separate functions per field
name, it's best to create a separate function for every single trigger.

You can alternatively use a language with fine control over SPI plan
caching like PL/Tcl. But then you loose exactly that optimization and
your trigger has to parse and plan this "SELECT lower('quotedval')" on
every single invocation. Do that only if you are sure to have ample
spare cpu cycles.
Jan

--
#================================================= =====================#
# It's easier to get forgiveness for being wrong than for being right. #
# Let's break this rule - forgive me. #
#================================================= = Ja******@Yahoo.com #
---------------------------(end of broadcast)---------------------------
TIP 7: don't forget to increase your free space map settings

Nov 11 '05 #3

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

Similar topics

1
by: Alex Vinokur | last post by:
========================= Windows 2000 Professional Digital Mars C/C++ 8.36 STLport 4.5.3 ========================= I have got a problem with compilation of the following piece of code using...
1
by: Dunc | last post by:
I'm new to Postgres, and getting nowhere with a PL/Perl trigger that I'm trying to write - hopefully, someone can give me some insight into what I'm doing wrong. My trigger is designed to reformat...
2
by: eczino | last post by:
I currently have a web form posting back to a SQL table using a Stored Procedure. Part of this SP is that it pulls data from another table and inserts a new row into the registration table. I...
4
by: Jules Alberts | last post by:
Hello everyone, I'm working on a tiny trigger function that needs to ensure that all values entered in a field are lowercase'd. I can't use pl/pgsql because I have a dozen different columns...
1
by: Barbara Lindsey | last post by:
I am a postgres newbie. I am trying to create a trigger that will put a copy of a record into a backup table before update or delete. As I understand it, in order to do this I must have a...
6
by: alederer | last post by:
Hallo! I have a table tstest(ts char(13) for bit data constraint a unique). This column is filled in a trigger with generate_unique(). In a application (CLI), I have the values of this...
8
by: Frank van Vugt | last post by:
Hi, If during a transaction a number of deferred triggers are fired, what will be their execution order upon the commit? Will they be executed in order of firing or alfabetically or...
1
by: Mario A. Soto Cordones | last post by:
Hi. anybody know how to sen a parameter an a trigger. thank for your help Mario Soto
1
by: djdevx | last post by:
Dear all PostgreSQL xperts! Hi, I am newbie in PostgreSQL. I am currently developing an app that use PostgreSQL as a BackEnd Database. Now I am having problem with the function trigger since last...
2
by: Kemmylinns12 | last post by:
Blockchain technology has emerged as a transformative force in the business world, offering unprecedented opportunities for innovation and efficiency. While initially associated with cryptocurrencies...
0
by: antdb | last post by:
Ⅰ. Advantage of AntDB: hyper-convergence + streaming processing engine In the overall architecture, a new "hyper-convergence" concept was proposed, which integrated multiple engines and...
0
hi
by: WisdomUfot | last post by:
It's an interesting question you've got about how Gmail hides the HTTP referrer when a link in an email is clicked. While I don't have the specific technical details, Gmail likely implements measures...
0
Oralloy
by: Oralloy | last post by:
Hello Folks, I am trying to hook up a CPU which I designed using SystemC to I/O pins on an FPGA. My problem (spelled failure) is with the synthesis of my design into a bitstream, not the C++...
0
BLUEPANDA
by: BLUEPANDA | last post by:
At BluePanda Dev, we're passionate about building high-quality software and sharing our knowledge with the community. That's why we've created a SaaS starter kit that's not only easy to use but also...
0
by: Rahul1995seven | last post by:
Introduction: In the realm of programming languages, Python has emerged as a powerhouse. With its simplicity, versatility, and robustness, Python has gained popularity among beginners and experts...
2
by: Ricardo de Mila | last post by:
Dear people, good afternoon... I have a form in msAccess with lots of controls and a specific routine must be triggered if the mouse_down event happens in any control. Than I need to discover what...
0
by: jack2019x | last post by:
hello, Is there code or static lib for hook swapchain present? I wanna hook dxgi swapchain present for dx11 and dx9.
0
by: F22F35 | last post by:
I am a newbie to Access (most programming for that matter). I need help in creating an Access database that keeps the history of each user in a database. For example, a user might have lesson 1 sent...

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.