1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/Attic/plsql.sgml,v 2.18 2001/01/20 20:59:29 petere Exp $
-->
<chapter id="plsql">
<title>PL/pgSQL - SQL Procedural Language</title>
<para>
PL/pgSQL is a loadable procedural language for the
<productname>Postgres</productname> database system.
</para>
<para>
This package was originally written by Jan Wieck.
</para>
<sect1 id="plsql-overview">
<title>Overview</title>
<para>
The design goals of PL/pgSQL were to create a loadable procedural
language that
<itemizedlist>
<listitem>
<para>
can be used to create functions and trigger procedures,
</para>
</listitem>
<listitem>
<para>
adds control structures to the <acronym>SQL</acronym> language,
</para>
</listitem>
<listitem>
<para>
can perform complex computations,
</para>
</listitem>
<listitem>
<para>
inherits all user defined types, functions and operators,
</para>
</listitem>
<listitem>
<para>
can be defined to be trusted by the server,
</para>
</listitem>
<listitem>
<para>
is easy to use.
</para>
</listitem>
</itemizedlist>
</para>
<para>
The PL/pgSQL call handler parses the functions source text and
produces an internal binary instruction tree on the first time the
function is called. The produced bytecode is identified
in the call handler by the object ID of the function. This ensures,
that changing a function by a DROP/CREATE sequence will take effect
without establishing a new database connection.
</para>
<para>
For all expressions and <acronym>SQL</acronym> statements used in
the function, the PL/pgSQL bytecode interpreter creates a
prepared execution plan using the SPI managers SPI_prepare() and
SPI_saveplan() functions. This is done the first time, the individual
statement is processed in the PL/pgSQL function. Thus, a function with
conditional code that contains many statements for which execution
plans would be required, will only prepare and save those plans
that are really used during the entire lifetime of the database
connection.
</para>
<para>
Except for input-/output-conversion and calculation functions
for user defined types, anything that can be defined in C language
functions can also be done with PL/pgSQL. It is possible to
create complex conditional computation functions and later use
them to define operators or use them in functional indices.
</para>
</sect1>
<!-- **** PL/pgSQL Description **** -->
<sect1 id="plpgsql-description">
<title>Description</title>
<!-- **** PL/pgSQL structure **** -->
<sect2>
<title>Structure of PL/pgSQL</title>
<para>
The PL/pgSQL language is case insensitive. All keywords and
identifiers can be used in mixed upper- and lowercase.
</para>
<para>
PL/pgSQL is a block oriented language. A block is defined as
<programlisting>
[<<label>>]
[DECLARE
<replaceable>declarations</replaceable>]
BEGIN
<replaceable>statements</replaceable>
END;
</programlisting>
</para>
<para>
There can be any number of sub-blocks in the statement section
of a block. Sub-blocks can be used to hide variables from outside a
block of statements. The variables
declared in the declarations section preceding a block are
initialized to their default values every time the block is entered,
not only once per function call.
</para>
<para>
It is important not to misunderstand the meaning of BEGIN/END for
grouping statements in PL/pgSQL and the database commands for
transaction control. Functions and trigger procedures cannot
start or commit transactions and <productname>Postgres</productname>
does not have nested transactions.
</para>
</sect2>
<sect2>
<title>Comments</title>
<para>
There are two types of comments in PL/pgSQL. A double dash '--'
starts a comment that extends to the end of the line. A '/*'
starts a block comment that extends to the next occurrence of '*/'.
Block comments cannot be nested, but double dash comments can be
enclosed into a block comment and a double dash can hide
the block comment delimiters '/*' and '*/'.
</para>
</sect2>
<!-- **** PL/pgSQL declarations **** -->
<sect2>
<title>Declarations</title>
<para>
All variables, rows and records used in a block or its
sub-blocks must be declared in the declarations section of a block
except for the loop variable of a FOR loop iterating over a range
of integer values. Parameters given to a PL/pgSQL function are
automatically declared with the usual identifiers $n.
The declarations have the following syntax:
</para>
<variablelist>
<varlistentry>
<term>
<replaceable>name</replaceable> [ CONSTANT ]
<replaceable>type</replaceable> [ NOT NULL ] [ DEFAULT | :=
<replaceable>value</replaceable> ];
</term>
<listitem>
<para>
Declares a variable of the specified base type. If the variable
is declared as CONSTANT, the value cannot be changed. If NOT NULL
is specified, an assignment of a NULL value results in a runtime
error. Since the default value of all variables is the
<acronym>SQL</acronym> NULL value, all variables declared as NOT NULL
must also have a default value specified.
</para>
<para>
The default value is evaluated every time the function is called. So
assigning '<replaceable>now</replaceable>' to a variable of type
<type>timestamp</type> causes the variable to have the
time of the actual function call, not when the function was
precompiled into its bytecode.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<replaceable>name</replaceable> <replaceable>table</replaceable>%ROWTYPE;
</term>
<listitem>
<para>
Declares a row with the structure of the given table. <replaceable>table</replaceable> must be
an existing table or view name of the database. The fields of the row
are accessed in the dot notation. Parameters to a function can
be composite types (complete table rows). In that case, the
corresponding identifier $n will be a rowtype, but it
must be aliased using the ALIAS command described below. Only the user
attributes of a table row are accessible in the row, no Oid or other
system attributes (hence the row could be from a view and view rows
don't have useful system attributes).
</para>
<para>
The fields of the rowtype inherit the table's field sizes
or precision for char() etc. data types.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<replaceable>name</replaceable> RECORD;
</term>
<listitem>
<para>
Records are similar to rowtypes, but they have no predefined structure.
They are used in selections and FOR loops to hold one actual
database row from a SELECT operation. One and the same record can be
used in different selections. Accessing a record or an attempt to assign
a value to a record field when there is no actual row in it results
in a runtime error.
</para>
<para>
The NEW and OLD rows in a trigger are given to the procedure as
records. This is necessary because in <productname>Postgres</productname>
one and the same trigger procedure can handle trigger events for
different tables.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<replaceable>name</replaceable> ALIAS FOR $n;
</term>
<listitem>
<para>
For better readability of the code it is possible to define an alias
for a positional parameter to a function.
</para>
<para>
This aliasing is required for composite types given as arguments to
a function. The dot notation $1.salary as in SQL functions is not
allowed in PL/pgSQL.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
RENAME <replaceable>oldname</replaceable> TO <replaceable>newname</replaceable>;
</term>
<listitem>
<para>
Change the name of a variable, record or row. This is useful
if NEW or OLD should be referenced by another name inside a
trigger procedure.
</para>
</listitem>
</varlistentry>
</variablelist>
</sect2>
<!-- **** PL/pgSQL data types **** -->
<sect2>
<title>Data Types</title>
<para>
The type of a variable can be any of the existing base types of
the database. <replaceable>type</replaceable> in the declarations
section above is defined as:
</para>
<para>
<itemizedlist>
<listitem>
<para>
<productname>Postgres</productname>-basetype
</para>
</listitem>
<listitem>
<para>
<replaceable>variable</replaceable>%TYPE
</para>
</listitem>
<listitem>
<para>
<replaceable>table.field</replaceable>%TYPE
</para>
</listitem>
</itemizedlist>
</para>
<para>
<replaceable>variable</replaceable> is the name of a variable,
previously declared in the
same function, that is visible at this point.
</para>
<para>
<replaceable>table</replaceable> is the name of an existing table
or view where <replaceable>field</replaceable> is the name of
an attribute.
</para>
<para>
Using the <replaceable>table.field</replaceable>%TYPE
causes PL/pgSQL to look up the attributes definitions at the
first call to the function during the lifetime of a backend.
Have a table with a char(20) attribute and some PL/pgSQL functions
that deal with its content in local variables. Now someone
decides that char(20) isn't enough, dumps the table, drops it,
recreates it now with the attribute in question defined as
char(40) and restores the data. Ha - he forgot about the
functions. The computations inside them will truncate the values
to 20 characters. But if they are defined using the
<replaceable>table.field</replaceable>%TYPE
declarations, they will automagically handle the size change or
if the new table schema defines the attribute as text type.
</para>
</sect2>
<!-- **** PL/pgSQL expressions **** -->
<sect2>
<title>Expressions</title>
<para>
All expressions used in PL/pgSQL statements are processed using
the backend's executor. Expressions that appear to contain
constants may in fact require run-time evaluation (e.g. 'now' for the
<type>timestamp</type> type) so
it is impossible for the PL/pgSQL parser
to identify real constant values other than the NULL keyword. All
expressions are evaluated internally by executing a query
<programlisting>
SELECT <replaceable>expression</replaceable>
</programlisting>
using the SPI manager. In the expression, occurrences of variable
identifiers are substituted by parameters and the actual values from
the variables are passed to the executor in the parameter array. All
expressions used in a PL/pgSQL function are only prepared and
saved once. The only exception to this rule is an EXECUTE statement
if parsing of a query is needed each time it is encountered.
</para>
<para>
The type checking done by the <productname>Postgres</productname>
main parser has some side
effects to the interpretation of constant values. In detail there
is a difference between what the two functions
<programlisting>
CREATE FUNCTION logfunc1 (text) RETURNS timestamp AS '
DECLARE
logtxt ALIAS FOR $1;
BEGIN
INSERT INTO logtable VALUES (logtxt, ''now'');
RETURN ''now'';
END;
' LANGUAGE 'plpgsql';
</programlisting>
and
<programlisting>
CREATE FUNCTION logfunc2 (text) RETURNS timestamp AS '
DECLARE
logtxt ALIAS FOR $1;
curtime timestamp;
BEGIN
curtime := ''now'';
INSERT INTO logtable VALUES (logtxt, curtime);
RETURN curtime;
END;
' LANGUAGE 'plpgsql';
</programlisting>
do. In the case of logfunc1(), the <productname>Postgres</productname>
main parser
knows when preparing the plan for the INSERT, that the string 'now'
should be interpreted as <type>timestamp</type> because the target field of logtable
is of that type. Thus, it will make a constant from it at this time
and this constant value is then used in all invocations of logfunc1()
during the lifetime of the backend. Needless to say that this isn't what the
programmer wanted.
</para>
<para>
In the case of logfunc2(), the <productname>Postgres</productname>
main parser does not know
what type 'now' should become and therefore it returns a data type of
text containing the string 'now'. During the assignment
to the local variable curtime, the PL/pgSQL interpreter casts this
string to the timestamp type by calling the text_out() and timestamp_in()
functions for the conversion.
</para>
<para>
This type checking done by the <productname>Postgres</productname> main
parser got implemented after PL/pgSQL was nearly done.
It is a difference between 6.3 and 6.4 and affects all functions
using the prepared plan feature of the SPI manager.
Using a local
variable in the above manner is currently the only way in PL/pgSQL to get
those values interpreted correctly.
</para>
<para>
If record fields are used in expressions or statements, the data types of
fields should not change between calls of one and the same expression.
Keep this in mind when writing trigger procedures that handle events
for more than one table.
</para>
</sect2>
<!-- **** PL/pgSQL statements **** -->
<sect2>
<title>Statements</title>
<para>
Anything not understood by the PL/pgSQL parser as specified below
will be put into a query and sent down to the database engine
to execute. The resulting query should not return any data.
</para>
<variablelist>
<varlistentry>
<term>Assignment</term>
<listitem>
<para>
An assignment of a value to a variable or row/record field is
written as
<programlisting>
<replaceable>identifier</replaceable> := <replaceable>expression</replaceable>;
</programlisting>
If the expressions result data type doesn't match the variables
data type, or the variable has a size/precision that is known
(as for char(20)), the result value will be implicitly casted by
the PL/pgSQL bytecode interpreter using the result types output- and
the variables type input-functions. Note that this could potentially
result in runtime errors generated by the types input functions.
</para>
<para>
An assignment of a complete selection into a record or row can
be done by
<programlisting>
SELECT INTO <replaceable>target</replaceable> <replaceable>expressions</replaceable> FROM ...;
</programlisting>
<replaceable>target</replaceable> can be a record, a row variable or a
comma separated list of variables and record-/row-fields.
</para>
<para>
if a row or a variable list is used as target, the selected values
must exactly match the structure of the target(s) or a runtime error
occurs. The FROM keyword can be followed by any valid qualification,
grouping, sorting etc. that can be given for a SELECT statement.
</para>
<para>
There is a special variable named FOUND of type bool that can be used
immediately after a SELECT INTO to check if an assignment had success.
<programlisting>
SELECT INTO myrec * FROM EMP WHERE empname = myname;
IF NOT FOUND THEN
RAISE EXCEPTION ''employee % not found'', myname;
END IF;
</programlisting>
If the selection returns multiple rows, only the first is moved
into the target fields. All others are silently discarded.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Calling another function</term>
<listitem>
<para>
All functions defined in a <productname>Postgres</productname>
database return a value. Thus, the normal way to call a function
is to execute a SELECT query or doing an assignment (resulting
in a PL/pgSQL internal SELECT). But there are cases where someone
is not interested in the function's result.
<programlisting>
PERFORM <replaceable>query</replaceable>
</programlisting>
executes a 'SELECT <replaceable>query</replaceable>' over the
SPI manager and discards the result. Identifiers like local
variables are still substituted into parameters.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Executing dynamic queries</term>
<listitem>
<cmdsynopsis>
<command>EXECUTE</command>
<arg choice="req"><replaceable class="command">query-string</replaceable></arg>
</cmdsynopsis>
<para>
where <replaceable>query-string</replaceable> is a string
of type TEXT containing the <replaceable>query</replaceable> to be executed.
</para>
<para>
Unlike all other queries in PL/pgSQL, a
<replaceable>query</replaceable> run by an EXECUTE statement
is not prepared and saved just once during the life of the
server. Instead, the <replaceable>query</replaceable> is
prepared each time the statement is run. The
<replaceable>query-string</replaceable> can be dynamically created
within the procedure to perform actions on variable tables and
fields.
</para>
<para>
The results from SELECT queries are discarded by EXECUTE unless
SELECT INTO is used to save the results into a table.
</para>
<para>
An example:
<programlisting>
EXECUTE ''UPDATE tbl SET ''
|| quote_ident(fieldname)
|| '' = ''
|| quote_literal(newvalue)
|| '' WHERE ...'';
</programlisting>
This example shows use of the functions
<function>quote_ident</function>(<type>TEXT</type>) and
<function>quote_literal</function>(<type>TEXT</type>).
Variables containing field and table identifiers should be
passed to function <function>quote_ident()</function>.
Variables containing literal elements of the dynamic query
string should be passed to
<function>quote_literal()</function>. Both take the
appropriate steps to return the input text enclosed in single
or double quotes and with any embedded special characters
intact.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Returning from the function</term>
<listitem>
<para>
<programlisting>
RETURN <replaceable>expression</replaceable>
</programlisting>
The function terminates and the value of <replaceable>expression</replaceable>
will be returned to the upper executor. The return value of a function
cannot be undefined. If control reaches the end of the top-level block
of the function without hitting a RETURN statement, a runtime error
will occur.
</para>
<para>
The expressions result will be automatically casted into the
function's return type as described for assignments.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Aborting and messages</term>
<listitem>
<para>
As indicated in the above examples there is a RAISE statement that
can throw messages into the <productname>Postgres</productname>
elog mechanism.
<programlisting>
RAISE <replaceable class="parameter">level</replaceable> '<replaceable class="parameter">format</replaceable>' [, <replaceable class="parameter">identifier</replaceable> [...]];
</programlisting>
Inside the format, "<literal>%</literal>" is used as a placeholder for the
subsequent comma-separated identifiers. Possible levels are
DEBUG (silently suppressed in production running databases), NOTICE
(written into the database log and forwarded to the client application)
and EXCEPTION (written into the database log and aborting the transaction).
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Conditionals</term>
<listitem>
<para>
<programlisting>
IF <replaceable>expression</replaceable> THEN
<replaceable>statements</replaceable>
[ELSE
<replaceable>statements</replaceable>]
END IF;
</programlisting>
The <replaceable>expression</replaceable> must return a value that
at least can be casted into a boolean type.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
Loops
</term>
<listitem>
<para>
There are multiple types of loops.
<programlisting>
[<<label>>]
LOOP
<replaceable>statements</replaceable>
END LOOP;
</programlisting>
An unconditional loop that must be terminated explicitly
by an EXIT statement. The optional label can be used by
EXIT statements of nested loops to specify which level of
nesting should be terminated.
<programlisting>
[<<label>>]
WHILE <replaceable>expression</replaceable> LOOP
<replaceable>statements</replaceable>
END LOOP;
</programlisting>
A conditional loop that is executed as long as the evaluation
of <replaceable>expression</replaceable> is true.
<programlisting>
[<<label>>]
FOR <replaceable>name</replaceable> IN [ REVERSE ] <replaceable>expression</replaceable> .. <replaceable>expression</replaceable> LOOP
<replaceable>statements</replaceable>
END LOOP;
</programlisting>
A loop that iterates over a range of integer values. The variable
<replaceable>name</replaceable> is automatically created as type
integer and exists only inside the loop. The two expressions giving
the lower and upper bound of the range are evaluated only when entering
the loop. The iteration step is always 1.
<programlisting>
[<<label>>]
FOR <replaceable>record | row</replaceable> IN <replaceable>select_clause</replaceable> LOOP
<replaceable>statements</replaceable>
END LOOP;
</programlisting>
The record or row is assigned all the rows resulting from the select
clause and the statements executed for each. If the loop is terminated
with an EXIT statement, the last assigned row is still accessible
after the loop.
<programlisting>
EXIT [ <replaceable>label</replaceable> ] [ WHEN <replaceable>expression</replaceable> ];
</programlisting>
If no <replaceable>label</replaceable> given,
the innermost loop is terminated and the
statement following END LOOP is executed next.
If <replaceable>label</replaceable> is given, it
must be the label of the current or an upper level of nested loop
blocks. Then the named loop or block is terminated and control
continues with the statement after the loops/blocks corresponding
END.
</para>
</listitem>
</varlistentry>
</variablelist>
</sect2>
<!-- **** PL/pgSQL trigger procedures **** -->
<sect2>
<title>Trigger Procedures</title>
<para>
PL/pgSQL can be used to define trigger procedures. They are created
with the usual CREATE FUNCTION command as a function with no
arguments and a return type of OPAQUE.
</para>
<para>
There are some <productname>Postgres</productname> specific details
in functions used as trigger procedures.
</para>
<para>
First they have some special variables created automatically in the
top-level blocks declaration section. They are
</para>
<variablelist>
<varlistentry>
<term>NEW</term>
<listitem>
<para>
Data type RECORD; variable holding the new database row on INSERT/UPDATE
operations on ROW level triggers.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>OLD</term>
<listitem>
<para>
Data type RECORD; variable holding the old database row on UPDATE/DELETE
operations on ROW level triggers.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TG_NAME</term>
<listitem>
<para>
Data type name; variable that contains the name of the trigger actually
fired.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TG_WHEN</term>
<listitem>
<para>
Data type text; a string of either 'BEFORE' or 'AFTER' depending on the
triggers definition.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TG_LEVEL</term>
<listitem>
<para>
Data type text; a string of either 'ROW' or 'STATEMENT' depending on the
triggers definition.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TG_OP</term>
<listitem>
<para>
Data type text; a string of 'INSERT', 'UPDATE' or 'DELETE' telling
for which operation the trigger is actually fired.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TG_RELID</term>
<listitem>
<para>
Data type oid; the object ID of the table that caused the
trigger invocation.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TG_RELNAME</term>
<listitem>
<para>
Data type name; the name of the table that caused the trigger
invocation.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TG_NARGS</term>
<listitem>
<para>
Data type integer; the number of arguments given to the trigger
procedure in the CREATE TRIGGER statement.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TG_ARGV[]</term>
<listitem>
<para>
Data type array of text; the arguments from the CREATE TRIGGER statement.
The index counts from 0 and can be given as an expression. Invalid
indices (< 0 or >= tg_nargs) result in a NULL value.
</para>
</listitem>
</varlistentry>
</variablelist>
<para>
Second they must return either NULL or a record/row containing
exactly the structure of the table the trigger was fired for.
Triggers fired AFTER might always return a NULL value with no
effect. Triggers fired BEFORE signal the trigger manager
to skip the operation for this actual row when returning NULL.
Otherwise, the returned record/row replaces the inserted/updated
row in the operation. It is possible to replace single values directly
in NEW and return that or to build a complete new record/row to
return.
</para>
</sect2>
<!-- **** PL/pgSQL exceptions **** -->
<sect2>
<title>Exceptions</title>
<para>
<productname>Postgres</productname> does not have a very smart
exception handling model. Whenever the parser, planner/optimizer
or executor decide that a statement cannot be processed any longer,
the whole transaction gets aborted and the system jumps back
into the main loop to get the next query from the client application.
</para>
<para>
It is possible to hook into the error mechanism to notice that this
happens. But currently it is impossible to tell what really
caused the abort (input/output conversion error, floating point
error, parse error). And it is possible that the database backend
is in an inconsistent state at this point so returning to the upper
executor or issuing more commands might corrupt the whole database.
And even if, at this point the information, that the transaction
is aborted, is already sent to the client application, so resuming
operation does not make any sense.
</para>
<para>
Thus, the only thing PL/pgSQL currently does when it encounters
an abort during execution of a function or trigger
procedure is to write some additional DEBUG level log messages
telling in which function and where (line number and type of
statement) this happened.
</para>
</sect2>
</sect1>
<!-- **** PL/pgSQL Examples **** -->
<sect1 id="plpgsql-examples">
<title>Examples</title>
<para>
Here are only a few functions to demonstrate how easy PL/pgSQL
functions can be written. For more complex examples the programmer
might look at the regression test for PL/pgSQL.
</para>
<para>
One painful detail of writing functions in PL/pgSQL is the handling
of single quotes. The function's source text on CREATE FUNCTION must
be a literal string. Single quotes inside of literal strings must be
either doubled or quoted with a backslash. We are still looking for
an elegant alternative. In the meantime, doubling the single quotes
as in the examples below should be used. Any solution for this
in future versions of <productname>Postgres</productname> will be
upward compatible.
</para>
<sect2>
<title>Some Simple PL/pgSQL Functions</title>
<para>
The following two PL/pgSQL functions are identical to their
counterparts from the C language function discussion.
<programlisting>
CREATE FUNCTION add_one (integer) RETURNS integer AS '
BEGIN
RETURN $1 + 1;
END;
' LANGUAGE 'plpgsql';
</programlisting>
<programlisting>
CREATE FUNCTION concat_text (text, text) RETURNS text AS '
BEGIN
RETURN $1 || $2;
END;
' LANGUAGE 'plpgsql';
</programlisting>
</para>
</sect2>
<sect2>
<title>PL/pgSQL Function on Composite Type</title>
<para>
Again it is the PL/pgSQL equivalent to the example from
The C functions.
<programlisting>
CREATE FUNCTION c_overpaid (EMP, integer) RETURNS bool AS '
DECLARE
emprec ALIAS FOR $1;
sallim ALIAS FOR $2;
BEGIN
IF emprec.salary ISNULL THEN
RETURN ''f'';
END IF;
RETURN emprec.salary > sallim;
END;
' LANGUAGE 'plpgsql';
</programlisting>
</para>
</sect2>
<sect2>
<title>PL/pgSQL Trigger Procedure</title>
<para>
This trigger ensures, that any time a row is inserted or updated
in the table, the current user name and time are stamped into the
row. And it ensures that an employees name is given and that the
salary is a positive value.
<programlisting>
CREATE TABLE emp (
empname text,
salary integer,
last_date timestamp,
last_user text);
CREATE FUNCTION emp_stamp () RETURNS OPAQUE AS '
BEGIN
-- Check that empname and salary are given
IF NEW.empname ISNULL THEN
RAISE EXCEPTION ''empname cannot be NULL value'';
END IF;
IF NEW.salary ISNULL THEN
RAISE EXCEPTION ''% cannot have NULL salary'', NEW.empname;
END IF;
-- Who works for us when she must pay for?
IF NEW.salary < 0 THEN
RAISE EXCEPTION ''% cannot have a negative salary'', NEW.empname;
END IF;
-- Remember who changed the payroll when
NEW.last_date := ''now'';
NEW.last_user := current_user;
RETURN NEW;
END;
' LANGUAGE 'plpgsql';
CREATE TRIGGER emp_stamp BEFORE INSERT OR UPDATE ON emp
FOR EACH ROW EXECUTE PROCEDURE emp_stamp();
</programlisting>
</para>
</sect2>
</sect1>
</chapter>
<!-- Keep this comment at the end of the file
Local variables:
mode:sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"./reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:("/usr/lib/sgml/catalog")
sgml-local-ecat-files:nil
End:
-->