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
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
1330
1331
1332
1333
1334
1335
1336
1337
1338
1339
1340
1341
1342
1343
1344
1345
1346
1347
1348
1349
1350
1351
1352
1353
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
1426
1427
1428
1429
1430
1431
1432
1433
1434
1435
1436
1437
1438
1439
1440
1441
1442
1443
1444
1445
1446
1447
1448
1449
1450
1451
1452
1453
1454
1455
1456
1457
1458
1459
1460
1461
1462
1463
1464
1465
1466
1467
1468
1469
1470
1471
1472
1473
1474
1475
1476
1477
1478
1479
1480
1481
1482
1483
1484
1485
1486
1487
1488
1489
1490
1491
1492
1493
1494
1495
1496
1497
1498
1499
1500
1501
1502
1503
1504
1505
1506
1507
1508
1509
1510
1511
1512
1513
1514
1515
1516
1517
1518
1519
1520
1521
1522
1523
1524
1525
1526
1527
1528
1529
1530
1531
1532
1533
1534
1535
1536
1537
1538
1539
1540
1541
1542
1543
1544
1545
1546
1547
1548
1549
1550
1551
1552
1553
1554
1555
1556
1557
1558
1559
1560
1561
1562
1563
1564
1565
1566
1567
1568
1569
1570
1571
1572
1573
1574
1575
1576
1577
1578
1579
1580
1581
1582
1583
1584
1585
1586
1587
1588
1589
1590
1591
1592
1593
1594
1595
1596
1597
1598
1599
1600
1601
1602
1603
1604
1605
|
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/xfunc.sgml,v 1.37 2001/09/15 19:56:59 petere Exp $
-->
<chapter id="xfunc">
<title id="xfunc-title">Extending <acronym>SQL</acronym>: Functions</title>
<sect1 id="xfunc-intro">
<title>Introduction</title>
<comment>
Historically, functions were perhaps considered a tool for creating
types. Today, few people build their own types but many write
their own functions. This introduction ought to be changed to
reflect this.
</comment>
<para>
As it turns out, part of defining a new type is the
definition of functions that describe its behavior.
Consequently, while it is possible to define a new
function without defining a new type, the reverse is
not true. We therefore describe how to add new functions
to <productname>Postgres</productname> before describing
how to add new types.
</para>
<para>
<productname>PostgreSQL</productname> provides four kinds of
functions:
<itemizedlist>
<listitem>
<para>
query language functions
(functions written in <acronym>SQL</acronym>)
</para>
</listitem>
<listitem>
<para>
procedural language
functions (functions written in, for example, <application>PL/Tcl</> or <application>PL/pgSQL</>)
</para>
</listitem>
<listitem>
<para>
internal functions
</para>
</listitem>
<listitem>
<para>
C language functions
</para>
</listitem>
</itemizedlist>
</para>
<para>
Every kind
of function can take a base type, a composite type or
some combination as arguments (parameters). In addition,
every kind of function can return a base type or
a composite type. It's easiest to define <acronym>SQL</acronym>
functions, so we'll start with those. Examples in this section
can also be found in <filename>funcs.sql</filename>
and <filename>funcs.c</filename> in the tutorial directory.
</para>
</sect1>
<sect1 id="xfunc-sql">
<title>Query Language (<acronym>SQL</acronym>) Functions</title>
<para>
SQL functions execute an arbitrary list of SQL statements, returning
the results of the last query in the list. SQL functions in general
return sets. If their returntype is not specified as a
<literal>SETOF</literal>,
then an arbitrary element of the last query's result will be returned.
</para>
<para>
The body of an SQL function should be a list of one or more SQL
statements separated by semicolons. Note that because the syntax
of the <command>CREATE FUNCTION</command> requires the body of the
function to be enclosed in single quotes, single quote marks used
in the body of the function must be escaped, by writing two single
quotes where one is desired.
</para>
<para>
Arguments to the SQL function may be referenced in the function
body using the syntax <literal>$<replaceable>n</></>: $1 refers to
the first argument, $2 to the second, and so on. If an argument
is of a composite type, then the <quote>dot notation</quote>,
e.g., <literal>$1.emp</literal>, may be used to access attributes
of the argument or to invoke functions.
</para>
<sect2>
<title>Examples</title>
<para>
To illustrate a simple SQL function, consider the following,
which might be used to debit a bank account:
<programlisting>
CREATE FUNCTION tp1 (integer, double precision) RETURNS integer AS '
UPDATE bank
SET balance = bank.balance - $2
WHERE bank.acctountno = $1;
SELECT 1;
' LANGUAGE SQL;
</programlisting>
A user could execute this function to debit account 17 by $100.00 as
follows:
<programlisting>
SELECT tp1(17, 100.0);
</programlisting>
</para>
<para>
The following more interesting example takes a single argument of
type <type>EMP</type>, which is really a table that contains data
about employees, and retrieves multiple results:
<programlisting>
CREATE FUNCTION hobbies (EMP) RETURNS SETOF hobbies AS '
SELECT hobbies.* FROM hobbies
WHERE $1.name = hobbies.person
' LANGUAGE SQL;
</programlisting>
</para>
</sect2>
<sect2>
<title><acronym>SQL</acronym> Functions on Base Types</title>
<para>
The simplest possible <acronym>SQL</acronym> function has no arguments and
simply returns a base type, such as <type>integer</type>:
<programlisting>
CREATE FUNCTION one() RETURNS integer AS '
SELECT 1 as RESULT;
' LANGUAGE SQL;
SELECT one() AS answer;
</programlisting>
<screen>
answer
--------
1
</screen>
</para>
<para>
Notice that we defined a column alias within the function body for the result of the function
(with the name <literal>RESULT</>), but this column alias is not visible
outside the function. Hence, the result is labelled <literal>answer</>
instead of <literal>one</>.
</para>
<para>
It is almost as easy to define <acronym>SQL</acronym> functions
that take base types as arguments. In the example below, notice
how we refer to the arguments within the function as <literal>$1</>
and <literal>$2</>:
<programlisting>
CREATE FUNCTION add_em(integer, integer) RETURNS integer AS '
SELECT $1 + $2;
' LANGUAGE SQL;
SELECT add_em(1, 2) AS answer;
</programlisting>
<screen>
answer
--------
3
</screen>
</para>
</sect2>
<sect2>
<title><acronym>SQL</acronym> Functions on Composite Types</title>
<para>
When specifying functions with arguments of composite
types (such as <type>EMP</type>), we must not only specify which
argument we want (as we did above with <literal>$1</> and <literal>$2</literal>) but
also the attributes of that argument. For example,
take the function <function>double_salary</function> that computes what your
salary would be if it were doubled:
<programlisting>
CREATE FUNCTION double_salary(EMP) RETURNS integer AS '
SELECT $1.salary * 2 AS salary;
' LANGUAGE SQL;
SELECT name, double_salary(EMP) AS dream
FROM EMP
WHERE EMP.cubicle ~= point '(2,1)';
</programlisting>
<screen>
name | dream
------+-------
Sam | 2400
</screen>
</para>
<para>
Notice the use of the syntax <literal>$1.salary</literal>.
Before launching into the subject of functions that
return composite types, we must first introduce the
function notation for projecting attributes. The simple way
to explain this is that we can usually use the
notations <literal>attribute(table)</> and <literal>table.attribute</> interchangably:
<programlisting>
--
-- this is the same as:
-- SELECT EMP.name AS youngster FROM EMP WHERE EMP.age < 30
--
SELECT name(EMP) AS youngster
FROM EMP
WHERE age(EMP) < 30;
</programlisting>
<screen>
youngster
-----------
Sam
</screen>
</para>
<para>
As we shall see, however, this is not always the case.
This function notation is important when we want to use
a function that returns a single row. We do this
by assembling the entire row within the function,
attribute by attribute. This is an example of a function
that returns a single <type>EMP</type> row:
<programlisting>
CREATE FUNCTION new_emp() RETURNS EMP AS '
SELECT text ''None'' AS name,
1000 AS salary,
25 AS age,
point ''(2,2)'' AS cubicle;
' LANGUAGE SQL;
</programlisting>
</para>
<para>
In this case we have specified each of the attributes
with a constant value, but any computation or expression
could have been substituted for these constants.
Defining a function like this can be tricky. Some of
the more important caveats are as follows:
<itemizedlist>
<listitem>
<para>
The target list order must be exactly the same as
that in which the attributes appear in the <command>CREATE
TABLE</command> statement that defined the table underlying the composite type.
</para>
</listitem>
<listitem>
<para>
You must typecast the expressions to match the
definition of the composite type, or you will get errors like this:
<screen>
<computeroutput>
ERROR: function declared to return emp returns varchar instead of text at column 1
</computeroutput>
</screen>
</para>
</listitem>
<listitem>
<para>
When calling a function that returns a row, we
cannot retrieve the entire row. We must either
project an attribute out of the row or pass the
entire row into another function.
<programlisting>
SELECT name(new_emp()) AS nobody;
</programlisting>
<screen>
nobody
--------
None
</screen>
</para>
</listitem>
<listitem>
<para>
The reason why, in general, we must use the function
syntax for projecting attributes of function return
values is that the parser just doesn't understand
the other (dot) syntax for projection when combined
with function calls.
<screen>
SELECT new_emp().name AS nobody;
NOTICE:parser: syntax error at or near "."
</screen>
</para>
</listitem>
</itemizedlist>
</para>
<para>
Any collection of commands in the <acronym>SQL</acronym>
language can be packaged together and defined as a function.
The commands can include data modification (i.e.,
<command>INSERT</command>, <command>UPDATE</command>, and
<command>DELETE</command>) as well
as <command>SELECT</command> queries. However, the final command
must be a <command>SELECT</command> that returns whatever is
specified as the function's return type.
<programlisting>
CREATE FUNCTION clean_EMP () RETURNS integer AS '
DELETE FROM EMP
WHERE EMP.salary <= 0;
SELECT 1 AS ignore_this;
' LANGUAGE SQL;
SELECT clean_EMP();
</programlisting>
<screen>
x
---
1
</screen>
</para>
</sect2>
</sect1>
<sect1 id="xfunc-pl">
<title>Procedural Language Functions</title>
<para>
Procedural languages aren't built into the <productname>PostgreSQL</productname> server; they are offered
by loadable modules. Please refer to the documentation of the
procedural language in question for details about the syntax and how the function body
is interpreted for each language.
</para>
<para>
There are currently four procedural languages available in the
standard <productname>PostgreSQL</productname> distribution:
<application>PL/pgSQL</application>, <application>PL/Tcl</application>,
<application>PL/Perl</application>, and <application>PL/Python</application>. Other languages can be
defined by users. Refer to <xref linkend="xplang"> for more
information. The basics of developing a new procedural language are covered in <xref linkend="xfunc-plhandler">.
</para>
</sect1>
<sect1 id="xfunc-internal">
<title>Internal Functions</title>
<para>
Internal functions are functions written in C that have been statically
linked into the <productname>PostgreSQL</productname> server.
The <quote>body</quote> of the function definition
specifies the C-language name of the function, which need not be the
same as the name being declared for SQL use.
(For reasons of backwards compatibility, an empty body
is accepted as meaning that the C-language function name is the
same as the SQL name.)
</para>
<para>
Normally, all internal functions present in the
backend are declared during the initialization of the database cluster (<command>initdb</command>),
but a user could use <command>CREATE FUNCTION</command>
to create additional alias names for an internal function.
Internal functions are declared in <command>CREATE FUNCTION</command>
with language name <literal>internal</literal>. For instance, to
create an alias for the <function>sqrt</function> function:
<programlisting>
CREATE FUNCTION square_root(double precision) RETURNS double precision
AS 'dsqrt'
LANGUAGE INTERNAL
WITH (isStrict);
</programlisting>
(Most internal functions expect to be declared <quote>strict</quote>.)
</para>
<note>
<para>
Not all <quote>predefined</quote> functions are
<quote>internal</quote> in the above sense. Some predefined
functions are written in SQL.
</para>
</note>
</sect1>
<sect1 id="xfunc-c">
<title>C Language Functions</title>
<para>
User-defined functions can be written in C (or a language that can
be made compatible with C, such as C++). Such functions are
compiled into dynamically loadable objects (also called shared
libraries) and are loaded by the server on demand. This
distinguishes them from internal functions.
</para>
<para>
Two different calling conventions are currently used for C functions.
The newer <quote>version 1</quote> calling convention is indicated by writing
a <literal>PG_FUNCTION_INFO_V1()</literal> macro call for the function,
as illustrated below. Lack of such a macro indicates an old-style
("version 0") function. The language name specified in <command>CREATE FUNCTION</command>
is <literal>C</literal> in either case. Old-style functions are now deprecated
because of portability problems and lack of functionality, but they
are still supported for compatibility reasons.
</para>
<sect2 id="xfunc-c-dynload">
<title>Dynamic Loading</title>
<para>
The first time a user-defined function in a particular
loadable object file is called in a backend session,
the dynamic loader loads that object file into memory so that the
function can be called. The <command>CREATE FUNCTION</command>
for a user-defined C function must therefore specify two pieces of
information for the function: the name of the loadable
object file, and the C name (link symbol) of the specific function to call
within that object file. If the C name is not explicitly specified then
it is assumed to be the same as the SQL function name.
<note>
<para>
After it is used for the first time, a dynamically loaded user
function is retained in memory, and future calls to the function
in the same session will only incur the small overhead of a symbol table
lookup.
</para>
</note>
</para>
<para>
The following algorithm is used to locate the shared object file
based on the name given in the <command>CREATE FUNCTION</command>
command:
<orderedlist>
<listitem>
<para>
If the name is an absolute file name, the given file is loaded.
</para>
</listitem>
<listitem>
<para>
If the name starts with the string <literal>$libdir</literal>,
that part is replaced by the PostgreSQL library directory,
which is determined at build time.
</para>
</listitem>
<listitem>
<para>
If the name does not contain a directory part, the file is
searched the path specified by the configuration variable
<varname>dynamic_library_path</varname>.
</para>
</listitem>
<listitem>
<para>
Otherwise (the file was not found in the path, or it contains a
non-absolute directory part), the dynamic loader will try to
take the name as given, which will most likely fail. (It is
unreliable to depend on the current working directory.)
</para>
</listitem>
</orderedlist>
If this sequence does not work, the platform-specific shared
library file name extension (often <filename>.so</filename>) is
appended to the given name and this sequence is tried again. If
that fails as well, the load will fail.
</para>
<note>
<para>
The user id the <application>PostgreSQL</application> server runs
as must be able to traverse the path to the file you intend to
load. Making the file or a higher-level directory not readable
and/or not executable by the <quote>postgres</quote> user is a
common mistake.
</para>
</note>
<para>
In any case, the file name that is specified in the
<command>CREATE FUNCTION</command> command is recorded literally
in the system catalogs, so if the file needs to be loaded again
the same procedure is applied.
</para>
<para>
It is recommended to locate shared libraries either relative to
<literal>$libdir</literal> or through the dynamic library path.
This simplifies version upgrades if the new installation is at a
different location.
</para>
<note>
<para>
<application>PostgreSQL</application> will not compile a function
automatically; it must be compiled before it is used in a CREATE
FUNCTION command. See <xref linkend="dfunc"> for additional information.
</para>
</note>
</sect2>
<sect2>
<title>Base Types in C-Language Functions</title>
<para>
<xref linkend="xfunc-c-type-table"> gives the C type required for
parameters in the C functions that will be loaded into Postgres.
The <quote>Defined In</quote> column gives the header file that
needs to be included to get the type definition. (The actual
definition may be in a different file that is included by the
listed file. It is recommended that users stick to the defined
interface.) Note that you should always include
<filename>postgres.h</filename> first in any source file, because
it declares a number of things that you will need anyway.
</para>
<table tocentry="1" id="xfunc-c-type-table">
<title>Equivalent C Types
for Built-In <productname>PostgreSQL</productname> Types</title>
<titleabbrev>Equivalent C Types</titleabbrev>
<tgroup cols="3">
<thead>
<row>
<entry>
SQL Type
</entry>
<entry>
C Type
</entry>
<entry>
Defined In
</entry>
</row>
</thead>
<tbody>
<row>
<entry><type>abstime</type></entry>
<entry><type>AbsoluteTime</type></entry>
<entry><filename>utils/nabstime.h</filename></entry>
</row>
<row>
<entry><type>boolean</type></entry>
<entry><type>bool</type></entry>
<entry><filename>postgres.h</filename> (maybe compiler built-in)</entry>
</row>
<row>
<entry><type>box</type></entry>
<entry><type>BOX*</type></entry>
<entry><filename>utils/geo-decls.h</filename></entry>
</row>
<row>
<entry><type>bytea</type></entry>
<entry><type>bytea*</type></entry>
<entry><filename>postgres.h</filename></entry>
</row>
<row>
<entry><type>"char"</type></entry>
<entry><type>char</type></entry>
<entry>(compiler built-in)</entry>
</row>
<row>
<entry><type>character</type></entry>
<entry><type>BpChar*</type></entry>
<entry><filename>postgres.h</filename></entry>
</row>
<row>
<entry><type>cid</type></entry>
<entry><type>CommandId</type></entry>
<entry><filename>postgres.h</filename></entry>
</row>
<row>
<entry><type>date</type></entry>
<entry><type>DateADT</type></entry>
<entry><filename>utils/date.h</filename></entry>
</row>
<row>
<entry><type>smallint</type> (<type>int2</type>)</entry>
<entry><type>int2</type> or <type>int16</type></entry>
<entry><filename>postgres.h</filename></entry>
</row>
<row>
<entry><type>int2vector</type></entry>
<entry><type>int2vector*</type></entry>
<entry><filename>postgres.h</filename></entry>
</row>
<row>
<entry><type>integer</type> (<type>int4</type>)</entry>
<entry><type>int4</type> or <type>int32</type></entry>
<entry><filename>postgres.h</filename></entry>
</row>
<row>
<entry><type>real</type> (<type>float4</type>)</entry>
<entry><type>float4*</type></entry>
<entry><filename>postgres.h</filename></entry>
</row>
<row>
<entry><type>double precision</type> (<type>float8</type>)</entry>
<entry><type>float8*</type></entry>
<entry><filename>postgres.h</filename></entry>
</row>
<row>
<entry><type>interval</type></entry>
<entry><type>Interval*</type></entry>
<entry><filename>utils/timestamp.h</filename></entry>
</row>
<row>
<entry><type>lseg</type></entry>
<entry><type>LSEG*</type></entry>
<entry><filename>utils/geo-decls.h</filename></entry>
</row>
<row>
<entry><type>name</type></entry>
<entry><type>Name</type></entry>
<entry><filename>postgres.h</filename></entry>
</row>
<row>
<entry><type>oid</type></entry>
<entry><type>Oid</type></entry>
<entry><filename>postgres.h</filename></entry>
</row>
<row>
<entry><type>oidvector</type></entry>
<entry><type>oidvector*</type></entry>
<entry><filename>postgres.h</filename></entry>
</row>
<row>
<entry><type>path</type></entry>
<entry><type>PATH*</type></entry>
<entry><filename>utils/geo-decls.h</filename></entry>
</row>
<row>
<entry><type>point</type></entry>
<entry><type>POINT*</type></entry>
<entry><filename>utils/geo-decls.h</filename></entry>
</row>
<row>
<entry><type>regproc</type></entry>
<entry><type>regproc</type></entry>
<entry><filename>postgres.h</filename></entry>
</row>
<row>
<entry><type>reltime</type></entry>
<entry><type>RelativeTime</type></entry>
<entry><filename>utils/nabstime.h</filename></entry>
</row>
<row>
<entry><type>text</type></entry>
<entry><type>text*</type></entry>
<entry><filename>postgres.h</filename></entry>
</row>
<row>
<entry><type>tid</type></entry>
<entry><type>ItemPointer</type></entry>
<entry><filename>storage/itemptr.h</filename></entry>
</row>
<row>
<entry><type>time</type></entry>
<entry><type>TimeADT</type></entry>
<entry><filename>utils/date.h</filename></entry>
</row>
<row>
<entry><type>time with time zone</type></entry>
<entry><type>TimeTzADT</type></entry>
<entry><filename>utils/date.h</filename></entry>
</row>
<row>
<entry><type>timestamp</type></entry>
<entry><type>Timestamp*</type></entry>
<entry><filename>utils/timestamp.h</filename></entry>
</row>
<row>
<entry><type>tinterval</type></entry>
<entry><type>TimeInterval</type></entry>
<entry><filename>utils/nabstime.h</filename></entry>
</row>
<row>
<entry><type>varchar</type></entry>
<entry><type>VarChar*</type></entry>
<entry><filename>postgres.h</filename></entry>
</row>
<row>
<entry><type>xid</type></entry>
<entry><type>TransactionId</type></entry>
<entry><filename>postgres.h</filename></entry>
</row>
</tbody>
</tgroup>
</table>
<para>
Internally, <productname>Postgres</productname> regards a
base type as a <quote>blob of memory</quote>. The user-defined
functions that you define over a type in turn define the
way that <productname>Postgres</productname> can operate
on it. That is, <productname>Postgres</productname> will
only store and retrieve the data from disk and use your
user-defined functions to input, process, and output the data.
Base types can have one of three internal formats:
<itemizedlist>
<listitem>
<para>
pass by value, fixed-length
</para>
</listitem>
<listitem>
<para>
pass by reference, fixed-length
</para>
</listitem>
<listitem>
<para>
pass by reference, variable-length
</para>
</listitem>
</itemizedlist>
</para>
<para>
By-value types can only be 1, 2 or 4 bytes in length
(also 8 bytes, if <literal>sizeof(Datum)</literal> is 8 on your machine).
You should be careful
to define your types such that they will be the same
size (in bytes) on all architectures. For example, the
<literal>long</literal> type is dangerous because it
is 4 bytes on some machines and 8 bytes on others, whereas
<type>int</type> type is 4 bytes on most
Unix machines. A reasonable implementation of
the <type>int4</type> type on Unix
machines might be:
<programlisting>
/* 4-byte integer, passed by value */
typedef int int4;
</programlisting>
<productname>PostgreSQL</productname> automatically figures
things out so that the integer types really have the size they
advertise.
</para>
<para>
On the other hand, fixed-length types of any size may
be passed by-reference. For example, here is a sample
implementation of a <productname>PostgreSQL</productname> type:
<programlisting>
/* 16-byte structure, passed by reference */
typedef struct
{
double x, y;
} Point;
</programlisting>
</para>
<para>
Only pointers to such types can be used when passing
them in and out of <productname>Postgres</productname> functions.
To return a value of such a type, allocate the right amount of
memory with <literal>palloc()</literal>, fill in the allocated memory,
and return a pointer to it. (Alternatively, you can return an input
value of the same type by returning its pointer. <emphasis>Never</>
modify the contents of a pass-by-reference input value, however.)
</para>
<para>
Finally, all variable-length types must also be passed
by reference. All variable-length types must begin
with a length field of exactly 4 bytes, and all data to
be stored within that type must be located in the memory
immediately following that length field. The
length field is the total length of the structure
(i.e., it includes the size of the length field
itself). We can define the text type as follows:
<programlisting>
typedef struct {
int4 length;
char data[1];
} text;
</programlisting>
</para>
<para>
Obviously, the data field shown here is not long enough to hold
all possible strings; it's impossible to declare such
a structure in <acronym>C</acronym>. When manipulating
variable-length types, we must be careful to allocate
the correct amount of memory and initialize the length field.
For example, if we wanted to store 40 bytes in a text
structure, we might use a code fragment like this:
<programlisting>
#include "postgres.h"
...
char buffer[40]; /* our source data */
...
text *destination = (text *) palloc(VARHDRSZ + 40);
destination->length = VARHDRSZ + 40;
memmove(destination->data, buffer, 40);
...
</programlisting>
</para>
<para>
Now that we've gone over all of the possible structures
for base types, we can show some examples of real functions.
</para>
</sect2>
<sect2>
<title>Version-0 Calling Conventions for C-Language Functions</title>
<para>
We present the <quote>old style</quote> calling convention first --- although
this approach is now deprecated, it's easier to get a handle on
initially. In the version-0 method, the arguments and result
of the C function are just declared in normal C style, but being
careful to use the C representation of each SQL data type as shown
above.
</para>
<para>
Here are some examples:
<programlisting>
#include "postgres.h"
#include <string.h>
/* By Value */
int
add_one(int arg)
{
return arg + 1;
}
/* By Reference, Fixed Length */
float8 *
add_one_float8(float8 *arg)
{
float8 *result = (float8 *) palloc(sizeof(float8));
*result = *arg + 1.0;
return result;
}
Point *
makepoint(Point *pointx, Point *pointy)
{
Point *new_point = (Point *) palloc(sizeof(Point));
new_point->x = pointx->x;
new_point->y = pointy->y;
return new_point;
}
/* By Reference, Variable Length */
text *
copytext(text *t)
{
/*
* VARSIZE is the total size of the struct in bytes.
*/
text *new_t = (text *) palloc(VARSIZE(t));
VARATT_SIZEP(new_t) = VARSIZE(t);
/*
* VARDATA is a pointer to the data region of the struct.
*/
memcpy((void *) VARDATA(new_t), /* destination */
(void *) VARDATA(t), /* source */
VARSIZE(t)-VARHDRSZ); /* how many bytes */
return new_t;
}
text *
concat_text(text *arg1, text *arg2)
{
int32 new_text_size = VARSIZE(arg1) + VARSIZE(arg2) - VARHDRSZ;
text *new_text = (text *) palloc(new_text_size);
VARATT_SIZEP(new_text) = new_text_size;
memcpy(VARDATA(new_text), VARDATA(arg1), VARSIZE(arg1)-VARHDRSZ);
memcpy(VARDATA(new_text) + (VARSIZE(arg1)-VARHDRSZ),
VARDATA(arg2), VARSIZE(arg2)-VARHDRSZ);
return new_text;
}
</programlisting>
</para>
<para>
Supposing that the above code has been prepared in file
<filename>funcs.c</filename> and compiled into a shared object,
we could define the functions to <productname>Postgres</productname>
with commands like this:
<programlisting>
CREATE FUNCTION add_one(int4) RETURNS int4
AS '<replaceable>PGROOT</replaceable>/tutorial/funcs.so' LANGUAGE 'c'
WITH (isStrict);
-- note overloading of SQL function name add_one()
CREATE FUNCTION add_one(float8) RETURNS float8
AS '<replaceable>PGROOT</replaceable>/tutorial/funcs.so',
'add_one_float8'
LANGUAGE 'c' WITH (isStrict);
CREATE FUNCTION makepoint(point, point) RETURNS point
AS '<replaceable>PGROOT</replaceable>/tutorial/funcs.so' LANGUAGE 'c'
WITH (isStrict);
CREATE FUNCTION copytext(text) RETURNS text
AS '<replaceable>PGROOT</replaceable>/tutorial/funcs.so' LANGUAGE 'c'
WITH (isStrict);
CREATE FUNCTION concat_text(text, text) RETURNS text
AS '<replaceable>PGROOT</replaceable>/tutorial/funcs.so' LANGUAGE 'c'
WITH (isStrict);
</programlisting>
</para>
<para>
Here <replaceable>PGROOT</replaceable> stands for the full path to
the <productname>Postgres</productname> source tree. Note that
depending on your system, the filename for a shared object might
not end in <literal>.so</literal>, but in <literal>.sl</literal>
or something else; adapt accordingly.
</para>
<para>
Notice that we have specified the functions as <quote>strict</quote>, meaning that
the system should automatically assume a NULL result if any input
value is NULL. By doing this, we avoid having to check for NULL inputs
in the function code. Without this, we'd have to check for NULLs
explicitly, for example by checking for a null pointer for each
pass-by-reference argument. (For pass-by-value arguments, we don't
even have a way to check!)
</para>
<para>
Although this calling convention is simple to use,
it is not very portable; on some architectures there are problems
with passing smaller-than-int data types this way. Also, there is
no simple way to return a NULL result, nor to cope with NULL arguments
in any way other than making the function strict. The version-1
convention, presented next, overcomes these objections.
</para>
</sect2>
<sect2>
<title>Version-1 Calling Conventions for C-Language Functions</title>
<para>
The version-1 calling convention relies on macros to suppress most
of the complexity of passing arguments and results. The C declaration
of a version-1 function is always
<programlisting>
Datum funcname(PG_FUNCTION_ARGS)
</programlisting>
In addition, the macro call
<programlisting>
PG_FUNCTION_INFO_V1(funcname);
</programlisting>
must appear in the same source file (conventionally it's written
just before the function itself). This macro call is not needed
for <literal>internal</>-language functions, since Postgres currently assumes
all internal functions are version-1. However, it is
<emphasis>required</emphasis> for dynamically-loaded functions.
</para>
<para>
In a version-1 function, each actual argument is fetched using a
<function>PG_GETARG_<replaceable>xxx</replaceable>()</function>
macro that corresponds to the argument's datatype, and the result
is returned using a
<function>PG_RETURN_<replaceable>xxx</replaceable>()</function>
macro for the return type.
</para>
<para>
Here we show the same functions as above, coded in version-1 style:
<programlisting>
#include "postgres.h"
#include <string.h>
#include "fmgr.h"
/* By Value */
PG_FUNCTION_INFO_V1(add_one);
Datum
add_one(PG_FUNCTION_ARGS)
{
int32 arg = PG_GETARG_INT32(0);
PG_RETURN_INT32(arg + 1);
}
/* By Reference, Fixed Length */
PG_FUNCTION_INFO_V1(add_one_float8);
Datum
add_one_float8(PG_FUNCTION_ARGS)
{
/* The macros for FLOAT8 hide its pass-by-reference nature */
float8 arg = PG_GETARG_FLOAT8(0);
PG_RETURN_FLOAT8(arg + 1.0);
}
PG_FUNCTION_INFO_V1(makepoint);
Datum
makepoint(PG_FUNCTION_ARGS)
{
/* Here, the pass-by-reference nature of Point is not hidden */
Point *pointx = PG_GETARG_POINT_P(0);
Point *pointy = PG_GETARG_POINT_P(1);
Point *new_point = (Point *) palloc(sizeof(Point));
new_point->x = pointx->x;
new_point->y = pointy->y;
PG_RETURN_POINT_P(new_point);
}
/* By Reference, Variable Length */
PG_FUNCTION_INFO_V1(copytext);
Datum
copytext(PG_FUNCTION_ARGS)
{
text *t = PG_GETARG_TEXT_P(0);
/*
* VARSIZE is the total size of the struct in bytes.
*/
text *new_t = (text *) palloc(VARSIZE(t));
VARATT_SIZEP(new_t) = VARSIZE(t);
/*
* VARDATA is a pointer to the data region of the struct.
*/
memcpy((void *) VARDATA(new_t), /* destination */
(void *) VARDATA(t), /* source */
VARSIZE(t)-VARHDRSZ); /* how many bytes */
PG_RETURN_TEXT_P(new_t);
}
PG_FUNCTION_INFO_V1(concat_text);
Datum
concat_text(PG_FUNCTION_ARGS)
{
text *arg1 = PG_GETARG_TEXT_P(0);
text *arg2 = PG_GETARG_TEXT_P(1);
int32 new_text_size = VARSIZE(arg1) + VARSIZE(arg2) - VARHDRSZ;
text *new_text = (text *) palloc(new_text_size);
VARATT_SIZEP(new_text) = new_text_size;
memcpy(VARDATA(new_text), VARDATA(arg1), VARSIZE(arg1)-VARHDRSZ);
memcpy(VARDATA(new_text) + (VARSIZE(arg1)-VARHDRSZ),
VARDATA(arg2), VARSIZE(arg2)-VARHDRSZ);
PG_RETURN_TEXT_P(new_text);
}
</programlisting>
</para>
<para>
The <command>CREATE FUNCTION</command> commands are the same as
for the version-0 equivalents.
</para>
<para>
At first glance, the version-1 coding conventions may appear to
be just pointless obscurantism. However, they do offer a number
of improvements, because the macros can hide unnecessary detail.
An example is that in coding add_one_float8, we no longer need to
be aware that float8 is a pass-by-reference type. Another
example is that the GETARG macros for variable-length types hide
the need to deal with fetching <quote>toasted</quote> (compressed or
out-of-line) values. The old-style <function>copytext</function>
and <function>concat_text</function> functions shown above are
actually wrong in the presence of toasted values, because they
don't call <function>pg_detoast_datum()</function> on their
inputs. (The handler for old-style dynamically-loaded functions
currently takes care of this detail, but it does so less
efficiently than is possible for a version-1 function.)
</para>
<para>
One big improvement in version-1 functions is better handling of NULL
inputs and results. The macro <function>PG_ARGISNULL(n)</function>
allows a function to test whether each input is NULL (of course, doing
this is only necessary in functions not declared <quote>strict</>).
As with the
<function>PG_GETARG_<replaceable>xxx</replaceable>()</function> macros,
the input arguments are counted beginning at zero.
To return a NULL result, execute <function>PG_RETURN_NULL()</function>;
this works in both strict and non-strict functions.
</para>
<para>
The version-1 function call conventions make it possible to
return <quote>set</quote> results and implement trigger functions and
procedural-language call handlers. Version-1 code is also more
portable than version-0, because it does not break ANSI C restrictions
on function call protocol. For more details see
<filename>src/backend/utils/fmgr/README</filename> in the source
distribution.
</para>
</sect2>
<sect2>
<title>Composite Types in C-Language Functions</title>
<para>
Composite types do not have a fixed layout like C
structures. Instances of a composite type may contain
null fields. In addition, composite types that are
part of an inheritance hierarchy may have different
fields than other members of the same inheritance hierarchy.
Therefore, <productname>Postgres</productname> provides
a procedural interface for accessing fields of composite types
from C. As <productname>Postgres</productname> processes
a set of rows, each row will be passed into your
function as an opaque structure of type <literal>TUPLE</literal>.
Suppose we want to write a function to answer the query
<programlisting>
SELECT name, c_overpaid(emp, 1500) AS overpaid
FROM emp
WHERE name = 'Bill' OR name = 'Sam';
</programlisting>
In the query above, we can define c_overpaid as:
<programlisting>
#include "postgres.h"
#include "executor/executor.h" /* for GetAttributeByName() */
bool
c_overpaid(TupleTableSlot *t, /* the current row of EMP */
int32 limit)
{
bool isnull;
int32 salary;
salary = DatumGetInt32(GetAttributeByName(t, "salary", &isnull));
if (isnull)
return (false);
return salary > limit;
}
/* In version-1 coding, the above would look like this: */
PG_FUNCTION_INFO_V1(c_overpaid);
Datum
c_overpaid(PG_FUNCTION_ARGS)
{
TupleTableSlot *t = (TupleTableSlot *) PG_GETARG_POINTER(0);
int32 limit = PG_GETARG_INT32(1);
bool isnull;
int32 salary;
salary = DatumGetInt32(GetAttributeByName(t, "salary", &isnull));
if (isnull)
PG_RETURN_BOOL(false);
/* Alternatively, we might prefer to do PG_RETURN_NULL() for null salary */
PG_RETURN_BOOL(salary > limit);
}
</programlisting>
</para>
<para>
<function>GetAttributeByName</function> is the
<productname>Postgres</productname> system function that
returns attributes out of the current row. It has
three arguments: the argument of type <type>TupleTableSlot*</type> passed into
the function, the name of the desired attribute, and a
return parameter that tells whether the attribute
is null. <function>GetAttributeByName</function> returns a Datum
value that you can convert to the proper datatype by using the
appropriate <function>DatumGet<replaceable>XXX</replaceable>()</function> macro.
</para>
<para>
The following query lets <productname>Postgres</productname>
know about the <function>c_overpaid</function> function:
<programlisting>
CREATE FUNCTION c_overpaid(emp, int4)
RETURNS bool
AS '<replaceable>PGROOT</replaceable>/tutorial/obj/funcs.so'
LANGUAGE 'c';
</programlisting>
</para>
<para>
While there are ways to construct new rows or modify
existing rows from within a C function, these
are far too complex to discuss in this manual.
</para>
</sect2>
<sect2>
<title>Writing Code</title>
<para>
We now turn to the more difficult task of writing
programming language functions. Be warned: this section
of the manual will not make you a programmer. You must
have a good understanding of <acronym>C</acronym>
(including the use of pointers and the malloc memory manager)
before trying to write <acronym>C</acronym> functions for
use with <productname>Postgres</productname>. While it may
be possible to load functions written in languages other
than <acronym>C</acronym> into <productname>Postgres</productname>,
this is often difficult (when it is possible at all)
because other languages, such as <acronym>FORTRAN</acronym>
and <acronym>Pascal</acronym> often do not follow the same
<firstterm>calling convention</firstterm>
as <acronym>C</acronym>. That is, other
languages do not pass argument and return values
between functions in the same way. For this reason, we
will assume that your programming language functions
are written in <acronym>C</acronym>.
</para>
<para>
The basic rules for building <acronym>C</acronym> functions
are as follows:
<itemizedlist>
<listitem>
<para>
Use <literal>pg_config --includedir-server</literal> to find
out where the PostgreSQL server header files are installed on
your system (or the system that your users will be running
on). This option is new with PostgreSQL 7.2. For PostgreSQL
7.1 you should use the option <option>--includedir</option>.
(<command>pg_config</command> will exit with a non-zero status
if it encounters an unknown option.) For releases prior to
7.1 you will have to guess, but since that was before the
current calling conventions were introduced, it is unlikely
that you want to support those releases.
</para>
</listitem>
<listitem>
<para>
When allocating memory, use the
<productname>Postgres</productname> routines
<function>palloc</function> and <function>pfree</function>
instead of the corresponding <acronym>C</acronym> library
routines <function>malloc</function> and
<function>free</function>. The memory allocated by
<function>palloc</function> will be freed automatically at the
end of each transaction, preventing memory leaks.
</para>
</listitem>
<listitem>
<para>
Always zero the bytes of your structures using
<function>memset</function> or <function>bzero</function>.
Several routines (such as the hash access method, hash join
and the sort algorithm) compute functions of the raw bits
contained in your structure. Even if you initialize all
fields of your structure, there may be several bytes of
alignment padding (holes in the structure) that may contain
garbage values.
</para>
</listitem>
<listitem>
<para>
Most of the internal <productname>Postgres</productname> types
are declared in <filename>postgres.h</filename>, while the function
manager interfaces (<symbol>PG_FUNCTION_ARGS</symbol>, etc.)
are in <filename>fmgr.h</filename>, so you will need to
include at least these two files. For portability reasons it's best
to include <filename>postgres.h</filename> <emphasis>first</>,
before any other system or user header files.
Including <filename>postgres.h</filename> will also include
<filename>elog.h</filename> and <filename>palloc.h</filename>
for you.
</para>
</listitem>
<listitem>
<para>
Symbol names defined within object files must not conflict
with each other or with symbols defined in the
<productname>PostgreSQL</productname> server executable. You
will have to rename your functions or variables if you get
error messages to this effect.
</para>
</listitem>
<listitem>
<para>
Compiling and linking your object code so that
it can be dynamically loaded into
<productname>Postgres</productname>
always requires special flags.
See <xref linkend="dfunc">
for a detailed explanation of how to do it for
your particular operating system.
</para>
</listitem>
</itemizedlist>
</para>
</sect2>
&dfunc;
</sect1>
<sect1 id="xfunc-overload">
<title>Function Overloading</title>
<para>
More than one function may be defined with the same name, so long
as the arguments they take are different. In other words,
function names can be <firstterm>overloaded</firstterm>. When a
query is executed, the server will determine which function to
call from the data types and the number of the provided arguments.
Overloading can also be used to simulate functions with a variable
number of arguments, up to a finite maximum number.
</para>
<para>
A function may also have the same name as an attribute. In the case
that there is an ambiguity between a function on a complex type and
an attribute of the complex type, the attribute will always be used.
</para>
<para>
When creating a family of overloaded functions, one should be
careful not to create ambiguities. For instance, given the
functions
<programlisting>
CREATE FUNCTION test(int, real) RETURNS ...
CREATE FUNCTION test(smallint, double precision) RETURNS ...
</programlisting>
it is not immediately clear which function would be called with
some trivial input like <literal>test(1, 1.5)</literal>. The
currently implemented resolution rules are described in the
<citetitle>User's Guide</citetitle>, but it is unwise to design a
system that subtly relies on this behavior.
</para>
<para>
When overloading C language functions, there is an additional
constraint: The C name of each function in the family of
overloaded functions must be different from the C names of all
other functions, either internal or dynamically loaded. If this
rule is violated, the behavior is not portable. You might get a
run-time linker error, or one of the functions will get called
(usually the internal one). The alternative form of the
<literal>AS</> clause for the SQL <command>CREATE
FUNCTION</command> command decouples the SQL function name from
the function name in the C source code. E.g.,
<programlisting>
CREATE FUNCTION test(int) RETURNS int
AS '<replaceable>filename</>', 'test_1arg'
LANGUAGE C;
CREATE FUNCTION test(int, int) RETURNS int
AS '<replaceable>filename</>', 'test_2arg'
LANGUAGE C;
</programlisting>
The names of the C functions here reflect one of many possible conventions.
</para>
<para>
Prior to <productname>PostgreSQL</productname> 7.0, this
alternative syntax did not exist. There is a trick to get around
the problem, by defining a set of C functions with different names
and then define a set of identically-named SQL function wrappers
that take the appropriate argument types and call the matching C
function.
</para>
</sect1>
<sect1 id="xfunc-plhandler">
<title>Procedural Language Handlers</title>
<para>
All calls to functions that are written in a language other than
the current <quote>version 1</quote> interface for compiled
languages, in particular in user-defined procedural languages, but
also functions written in SQL or the version 0 compiled language
interface, go through a <firstterm>call handler</firstterm>
function for the specific language. It is the responsibility of
the call handler to execute the function in a meaningful way, such
as by interpreting the supplied source text. This section
describes how a language call handler can be written. This is not
a common task, in fact, it has only been done a handful of times
in the history of <productname>PostgreSQL</productname>, but the
topic naturally belongs in this chapter, and the material might
give some insight into the extensible nature of the
<productname>PostgreSQL</productname> system.
</para>
<para>
The call handler for a procedural language is a
<quote>normal</quote> function, which must be written in a
compiled language such as C and registered with
<productname>PostgreSQL</productname> as taking no arguments and
returning the <type>opaque</type> type, a placeholder for
unspecified or undefined types. This prevents the call handler
from being called directly as a function from queries. (However,
arguments may be supplied in the actual call to the handler when a
function in the language offered by the handler is to be
executed.)
</para>
<note>
<para>
In <productname>PostgreSQL</productname> 7.1 and later, call
handlers must adhere to the <quote>version 1</quote> function
manager interface, not the old-style interface.
</para>
</note>
<para>
The call handler is called in the same way as any other function:
It receives a pointer to a
<structname>FunctionCallInfoData</structname> struct containing
argument values and information about the called function, and it
is expected to return a <type>Datum</type> result (and possibly
set the <structfield>isnull</structfield> field of the
<structname>FunctionCallInfoData</structname> struct, if it wishes
to return an SQL NULL result). The difference between a call
handler and an ordinary callee function is that the
<structfield>flinfo->fn_oid</structfield> field of the
<structname>FunctionCallInfoData</structname> struct will contain
the OID of the actual function to be called, not of the call
handler itself. The call handler must use this field to determine
which function to execute. Also, the passed argument list has
been set up according to the declaration of the target function,
not of the call handler.
</para>
<para>
It's up to the call handler to fetch the
<classname>pg_proc</classname> entry and to analyze the argument
and return types of the called procedure. The AS clause from the
<command>CREATE FUNCTION</command> of the procedure will be found
in the <literal>prosrc</literal> attribute of the
<classname>pg_proc</classname> table entry. This may be the source
text in the procedural language itself (like for PL/Tcl), a
path name to a file, or anything else that tells the call handler
what to do in detail.
</para>
<para>
Often, the same function is called many times per SQL statement.
A call handler can avoid repeated lookups of information about the
called function by using the
<structfield>flinfo->fn_extra</structfield> field. This will
initially be NULL, but can be set by the call handler to point at
information about the PL function. On subsequent calls, if
<structfield>flinfo->fn_extra</structfield> is already non-NULL
then it can be used and the information lookup step skipped. The
call handler must be careful that
<structfield>flinfo->fn_extra</structfield> is made to point at
memory that will live at least until the end of the current query,
since an <structname>FmgrInfo</structname> data structure could be
kept that long. One way to do this is to allocate the extra data
in the memory context specified by
<structfield>flinfo->fn_mcxt</structfield>; such data will
normally have the same lifespan as the
<structname>FmgrInfo</structname> itself. But the handler could
also choose to use a longer-lived context so that it can cache
function definition information across queries.
</para>
<para>
When a PL function is invoked as a trigger, no explicit arguments
are passed, but the
<structname>FunctionCallInfoData</structname>'s
<structfield>context</structfield> field points at a
<structname>TriggerData</structname> node, rather than being NULL
as it is in a plain function call. A language handler should
provide mechanisms for PL functions to get at the trigger
information.
</para>
<para>
This is a template for a PL handler written in C:
<programlisting>
#include "postgres.h"
#include "executor/spi.h"
#include "commands/trigger.h"
#include "utils/elog.h"
#include "fmgr.h"
#include "access/heapam.h"
#include "utils/syscache.h"
#include "catalog/pg_proc.h"
#include "catalog/pg_type.h"
PG_FUNCTION_INFO_V1(plsample_call_handler);
Datum
plsample_call_handler(PG_FUNCTION_ARGS)
{
Datum retval;
if (CALLED_AS_TRIGGER(fcinfo))
{
/*
* Called as a trigger procedure
*/
TriggerData *trigdata = (TriggerData *) fcinfo->context;
retval = ...
}
else {
/*
* Called as a function
*/
retval = ...
}
return retval;
}
</programlisting>
</para>
<para>
Only a few thousand lines of code have to be added instead of the
dots to complete the call handler. See <xref linkend="xfunc-c">
for information on how to compile it into a loadable module.
</para>
<para>
The following commands then register the sample procedural
language:
<programlisting>
CREATE FUNCTION plsample_call_handler () RETURNS opaque
AS '/usr/local/pgsql/lib/plsample.so'
LANGUAGE C;
CREATE LANGUAGE plsample
HANDLER plsample_call_handler;
</programlisting>
</para>
</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:
-->
|