funcs.sql
and C-code/funcs.c.
CREATE FUNCTION one() RETURNS int4
AS 'SELECT 1 as RESULT' LANGUAGE 'sql';
SELECT one() AS answer;
+-------+
|answer |
+-------+
|1 |
+-------+
Notice that we defined a target list for the function
(with the name RESULT), but the target list of the
query that invoked the function overrode the function's
target list. Hence, the result is labelled answer
instead of one.
It's almost as easy to define SQL functions that take base types as arguments. In the example below, notice how we refer to the arguments within the function as $1 and $2.
CREATE FUNCTION add_em(int4, int4) RETURNS int4
AS 'SELECT $1 + $2;' LANGUAGE 'sql';
SELECT add_em(1, 2) AS answer;
+-------+
|answer |
+-------+
|3 |
+-------+
CREATE FUNCTION double_salary(EMP) RETURNS int4
AS 'SELECT $1.salary * 2 AS salary;' LANGUAGE 'sql';
SELECT name, double_salary(EMP) AS dream
FROM EMP
WHERE EMP.dept = 'toy';
+-----+-------+
|name | dream |
+-----+-------+
|Sam | 2400 |
+-----+-------+
Notice the use of the syntax $1.salary.
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
notation attribute(class) and class.attribute interchangably.
--
-- 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;
+----------+
|youngster |
+----------+
|Sam |
+----------+
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 instance. We do this
by assembling the entire instance within the function,
attribute by attribute. This is an example of a function
that returns a single EMP instance:
CREATE FUNCTION new_emp() RETURNS EMP
AS 'SELECT \'None\'::text AS name,
1000 AS salary,
25 AS age,
\'none\'::char16 AS dept;'
LANGUAGE 'sql';
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:
WARN::function declared to return type EMP does not retrieve (EMP.*)
SELECT name(new_emp()) AS nobody;
+-------+
|nobody |
+-------+
|None |
+-------+
SELECT new_emp().name AS nobody;
WARN:parser: syntax error at or near "."
CREATE FUNCTION clean_EMP () RETURNS int4
AS 'DELETE FROM EMP WHERE EMP.salary <= 0;
SELECT 1 AS ignore_this'
LANGUAGE 'sql';
SELECT clean_EMP();
+--+
|x |
+--+
|1 |
+--+
/* 4-byte integer, passed by value */
typedef int int4;
On the other hand, fixed-length types of any size may
be passed by-reference. For example, here is a sample
implementation of the POSTGRES char16 type:
/* 16-byte structure, passed by reference */
typedef struct {
char data[16];
} char16;
Only pointers to such types can be used when passing
them in and out of POSTGRES functions.
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:
typedef struct {
int4 length;
char data[1];
} text;
Obviously, the data field is not long enough to hold
all possible strings -- it's impossible to declare such
a structure in C. 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:
#include "postgres.h"
#include "utils/palloc.h"
...
char buffer[40]; /* our source data */
...
text *destination = (text *) palloc(VARHDRSZ + 40);
destination->length = VARHDRSZ + 40;
memmove(destination->data, buffer, 40);
...
Now that we've gone over all of the possible structures
for base types, we can show some examples of real functions.
Suppose funcs.c look like:
#include <string.h>
#include "postgres.h" /* for char16, etc. */
#include "utils/palloc.h" /* for palloc */
int
add_one(int arg)
{
return(arg + 1);
}
char16 *
concat16(char16 *arg1, char16 *arg2)
{
char16 *new_c16 = (char16 *) palloc(sizeof(char16));
memset((void *) new_c16, 0, sizeof(char16));
(void) strncpy(new_c16, arg1, 16);
return (char16 *)(strncat(new_c16, arg2, 16));
}
text *
copytext(text *t)
{
/*
* VARSIZE is the total size of the struct in bytes.
*/
text *new_t = (text *) palloc(VARSIZE(t));
memset(new_t, 0, VARSIZE(t));
VARSIZE(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);
}
On OSF/1 we would type:
CREATE FUNCTION add_one(int4) RETURNS int4
AS '/usr/local/postgres95/tutorial/obj/funcs.so' LANGUAGE 'c';
CREATE FUNCTION concat16(char16, char16) RETURNS char16
AS '/usr/local/postgres95/tutorial/obj/funcs.so' LANGUAGE 'c';
CREATE FUNCTION copytext(text) RETURNS text
AS '/usr/local/postgres95/tutorial/obj/funcs.so' LANGUAGE 'c';
On other systems, we might have to make the filename
end in .sl (to indicate that it's a shared library).
* SELECT name, c_overpaid(EMP, 1500) AS overpaid
FROM EMP
WHERE name = 'Bill' or name = 'Sam';
In the query above, we can define c_overpaid as:
#include "postgres.h" /* for char16, etc. */
#include "libpq-fe.h" /* for TUPLE */
bool
c_overpaid(TUPLE t,/* the current instance of EMP */
int4 limit)
{
bool isnull = false;
int4 salary;
salary = (int4) GetAttributeByName(t, "salary", &isnull);
if (isnull)
return (false);
return(salary > limit);
}
GetAttributeByName is the POSTGRES system function that
returns attributes out of the current instance. It has
three arguments: the argument of type TUPLE passed into
the function, the name of the desired attribute, and a
return parameter that describes whether the attribute
is null. GetAttributeByName will align data properly
so you can cast its return value to the desired type.
For example, if you have an attribute name which is of
the type char16, the GetAttributeByName call would look
like:
char *str;
...
str = (char *) GetAttributeByName(t, "name", &isnull)
The following query lets POSTGRES know about the
c_overpaid function:
* CREATE FUNCTION c_overpaid(EMP, int4) RETURNS bool
AS '/usr/local/postgres95/tutorial/obj/funcs.so' LANGUAGE 'c';
While there are ways to construct new instances or modify
existing instances from within a C function, these
are far too complex to discuss in this manual.
-I/usr/local/postgres95/includeon your cc command lines. Sometimes, you may find that you require header files that are in the server source itself (i.e., you need a file we neglected to install in include). In those cases you may need to add one or more of
-I/usr/local/postgres95/src/backend
-I/usr/local/postgres95/src/backend/include
-I/usr/local/postgres95/src/backend/port/<PORTNAME>
-I/usr/local/postgres95/src/backend/obj
(where <PORTNAME> is the name of the port, e.g.,
alpha or sparc).