Extending SQL: Functions
  
   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 Postgres before  describing  
   how  to  add  new types.
  
  
   Postgres  SQL  
   provides  three types of functions:
   
    
     
      query language functions 
      (functions written in SQL)
     
    
    
     
      procedural language 
      functions (functions written in, for example, PLTCL or PLSQL)
     
    
    
     
      programming  
      language  functions  (functions  written in a compiled 
      programming language such as C)
     
    
   
   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 SQL 
   functions, so we'll start with those.  Examples in this section 
   can also be found in funcs.sql 
   and funcs.c.
  
  
   Query Language (SQL) Functions
   
    SQL functions execute an arbitrary list of SQL queries, returning
    the results of the last query in the list.  SQL functions in general
    return sets.  If their returntype is not specified as a
    setof,
    then an arbitrary element of the last query's result will be returned.
   
   
    The body of a SQL function following AS
    should be a list of queries separated by whitespace characters and
    bracketed within quotation marks.  Note that quotation marks used in
    the queries must be escaped, by preceding them with two
    backslashes.
   
   
    Arguments to the SQL function may be referenced in the queries using
    a $n syntax: $1 refers to the first argument, $2 to the second, and so
    on.  If an argument is complex, then a dot
    notation (e.g. "$1.emp") may be
    used to access attributes of the argument or
    to invoke functions.
   
   
    Examples
    
     To illustrate a simple SQL function, consider the following,
     which might be used to debit a bank account:
     
create function TP1 (int4, float8) returns int4
    as 'update BANK set balance = BANK.balance - $2
        where BANK.acctountno = $1
        select(x = 1)'
    language 'sql';
     
     A user could execute this function to debit account 17 by $100.00 as
     follows:
     
select (x = TP1( 17,100.0));
     
    
    
     The following more interesting example takes a single argument of type
     EMP, and retrieves multiple results:
     
select function hobbies (EMP) returns set of HOBBIES
    as 'select (HOBBIES.all) from HOBBIES
        where $1.name = HOBBIES.person'
    language 'sql';
     
    
   
   
    SQL Functions on Base Types
    
     The simplest possible SQL function has no arguments and
     simply returns a base type, such as int4:
     
     
    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      |
         +-------+
     
    
   
   
    SQL Functions on Composite Types
    
     When  specifying  functions with arguments of composite
     types (such as EMP), we must  not  only  specify  which
     argument  we  want (as we did above with $1 and $2) but
     also the attributes of  that  argument.   For  example,
     take the function double_salary that computes what your
     salary would be if it were doubled:
     
    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.cubicle ~= '(2,1)'::point;
     
         +-----+-------+
         |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,
       \'(2,2)\'::point AS cubicle'
      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:
     
      
       
	The  target  list  order must be exactly the same as
	that in which the attributes appear  in  the  CREATE
	TABLE statement (or when you execute a .*  query).
       
      
      
       
	You must typecast the expressions (using ::) very carefully 
	or you will see  the  following error:
	
	 
WARN::function declared to return type EMP does not retrieve (EMP.*)
	 
	
       
      
      
       
	When calling a function that returns an instance, we
        cannot retrieve the entire instance.  We must either
        project an attribute out of the instance or pass the
        entire instance into another function.
	
    SELECT name(new_emp()) AS nobody;
            +-------+
            |nobody |
            +-------+
            |None   |
            +-------+
	
       
      
      
       
	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.
	
            SELECT new_emp().name AS nobody;
            WARN:parser: syntax error at or near "."
	
       
      
     
         
    
     Any collection of commands in the  SQL  query  
     language can be packaged together and defined as a function.
     The commands can include updates (i.e.,
     INSERT, UPDATE, and
     DELETE) as well
     as SELECT queries.  However, the final command 
     must be a SELECT that returns whatever is
     specified as the function's returntype.
     
    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 |
         +--+
         
     
    
   
  
  
   Procedural Language Functions
   
    Procedural languages aren't built into Postgres. They are offered
    by loadable modules. Please refer to the documentation for the
    PL in question for details about the syntax and how the AS
    clause is interpreted by the PL handler.
   
   
    There are two procedural languages available with the standard
    Postgres distribution (PLTCL and PLSQL), and other
    languages can be defined.
    Refer to  for
    more information.
   
  
  
   Internal Functions
   
    Internal functions are functions written in C which have been statically
    linked into the Postgres backend
    process. The AS
    clause gives 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 AS
    string is accepted as meaning that the C-language function name is the
    same as the SQL name.)  Normally, all internal functions present in the
    backend are declared as SQL functions during database initialization,
    but a user could use CREATE FUNCTION
    to create additional alias names for an internal function.
   
  
  
   Compiled (C) Language Functions
   
    Functions written in C can be compiled into dynamically loadable
    objects, and used to implement user-defined SQL functions.  The
    first time the user defined function is called inside the backend,
    the dynamic loader loads the function's object code into memory,
    and links the function with the running
    Postgres executable.  The SQL syntax
    for CREATE FUNCTION
    links the SQL function
    to the C source function in one of two ways. If the SQL function
    has the same name as the C source function the first form of the
    statement is used. The string argument in the AS clause is the
    full pathname of the file that contains the dynamically loadable
    compiled object.  If the name of the C function is different from the
    desired name of the SQL function, then the second form is used. In this
    form the AS clause takes two string arguments, the first is the
    full pathname of the dynamically loadable object file, and the
    second is the link symbol that the dynamic loader should search
    for. This link symbol is just the function name in the C source
    code.
    
     
      After it is used for the first time, a dynamically loaded, user
      function is retained in memory, and future calls to the function
      only incur the small overhead of a symbol table lookup.
     
    
   
   
    The string which specifies the object file (the string in the AS
    clause) should be the full path of the object
    code file for the function, bracketed by quotation marks.  If a
    link symbol is used in the AS clause, the link symbol should also be
    bracketed by single quotation marks, and should be exactly the
    same as the name of the function in the C source code. On Unix systems
    the command nm will print all of the link
    symbols in a dynamically loadable object.
    (Postgres will not compile a function
    automatically; it must be compiled before it is used in a CREATE
    FUNCTION command.  See below for additional information.)
   
   
    C Language Functions on Base Types
    
     The following table gives the C type required for parameters in the C
     functions that will be loaded into Postgres.  The "Defined In"
     column gives the actual header file (in the
     .../src/backend/
     directory) that the equivalent C type is defined.  However, if you
     include utils/builtins.h,
     these files will automatically be
     included.
     
      Equivalent C Types
       for Built-In Postgres Types
      Equivalent C Types
      
       
	
	 
	  Built-In Type
	 
	 
	  C Type
	 
	 
	  Defined In
	 
	
       
       
	
	 abstime
	 AbsoluteTime
	 utils/nabstime.h
	
	
	 bool
	 bool
	 include/c.h
	
	
	 box
	 (BOX *)
	 utils/geo-decls.h
	
	
	 bytea
	 (bytea *)
	 include/postgres.h
	
	
	 char
	 char
	 N/A
	
	
	 cid
	 CID
	 include/postgres.h
	
	
	 datetime
	 (DateTime *)
	 include/c.h or include/postgres.h
	
	
	 int2
	 int2
	 include/postgres.h
	
	
	 int2vector
	 (int2vector *)
	 include/postgres.h
	
	
	 int4
	 int4
	 include/postgres.h
	
	
	 float4
	 float32 or (float4 *)
	include/c.h or include/postgres.h
	
	
	 float8
	 float64 or (float8 *)
	 include/c.h or include/postgres.h
	
	
	 lseg
	 (LSEG *)
	 include/geo-decls.h
	
	
	 name
	 (Name)
	 include/postgres.h
	
	
	 oid
	 oid
	 include/postgres.h
	
	
	 oidvector
	 (oidvector *)
	 include/postgres.h
	
	
	 path
	 (PATH *)
	 utils/geo-decls.h
	
	
	 point
	 (POINT *)
	 utils/geo-decls.h
	
	
	 regproc
	 regproc or REGPROC
	 include/postgres.h
	
	
	 reltime
	 RelativeTime
	 utils/nabstime.h
	
	
	 text
	 (text *)
	 include/postgres.h
	
	
	 tid
	 ItemPointer
	 storage/itemptr.h
	
	
	 timespan
	 (TimeSpan *)
	 include/c.h or include/postgres.h
	
	
	 tinterval
	 TimeInterval
	 utils/nabstime.h
	
	
	 uint2
	 uint16
	 include/c.h
	
	
	 uint4
	 uint32
	 include/c.h
	
	
	 xid
	 (XID *)
	 include/postgres.h
	
       
      
     
    
    
     Internally, Postgres regards a
     base type as a "blob  of memory."   The  user-defined  
     functions that you define over a type in turn define the 
     way  that  Postgres can operate  
     on  it.  That is, Postgres 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:
     
      
       
	pass by value, fixed-length
       
      
      
       
	pass by reference, fixed-length
       
      
      
       
	pass by reference, variable-length
       
      
     
    
    
     By-value  types  can  only be 1, 2 or 4 bytes in length
     (even if your computer supports by-value types of other
     sizes).   Postgres  itself 
     only passes integer types by value.  You should be careful 
     to define your types such that  they  will  be  the  same  
     size (in bytes) on all architectures.  For example, the 
     long type is dangerous because  it  
     is 4 bytes on some machines and 8 bytes on others, whereas 
     int  type  is  4  bytes  on  most  
     Unix machines  (though  not  on most 
     personal computers).  A reasonable implementation of  
     the  int4  type  on  Unix
     machines might be:
     
     
/* 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 a Postgres type:
     
     
/* 16-byte structure, passed by reference */
typedef struct
{
    double  x, y;
} Point;
     
    
    
     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"
...
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"
         /* By Value */
         
         int
         add_one(int arg)
         {
             return(arg + 1);
         }
         
         /* By Reference, Fixed Length */
         
         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));
             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);
         }
         
         text *
         concat_text(text *arg1, text *arg2)
         {
             int32 new_text_size = VARSIZE(arg1) + VARSIZE(arg2) - VARHDRSZ;
             text *new_text = (text *) palloc(new_text_size);
             memset((void *) new_text, 0, new_text_size);
             VARSIZE(new_text) = new_text_size;
             strncpy(VARDATA(new_text), VARDATA(arg1), VARSIZE(arg1)-VARHDRSZ);
             strncat(VARDATA(new_text), VARDATA(arg2), VARSIZE(arg2)-VARHDRSZ);
             return (new_text);
         }
     
    
    
     On OSF/1 we would type:
     
     
         CREATE FUNCTION add_one(int4) RETURNS int4
              AS 'PGROOT/tutorial/funcs.so' LANGUAGE 'c';
         CREATE FUNCTION makepoint(point, point) RETURNS point
              AS 'PGROOT/tutorial/funcs.so' LANGUAGE 'c';
    
         CREATE FUNCTION concat_text(text, text) RETURNS text
              AS 'PGROOT/tutorial/funcs.so' LANGUAGE 'c';
                                  
         CREATE FUNCTION copytext(text) RETURNS text
              AS 'PGROOT/tutorial/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).
    
   
   
    C Language Functions on Composite Types
    
     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,  Postgres  provides  
     a  procedural interface for accessing fields of composite types  
     from C.  As Postgres processes 
     a set of instances, each instance will be passed into your 
     function as an  opaque  structure of type TUPLE.
     Suppose we want to write a function to answer the query
     
         * 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"
         #include "executor/executor.h"  /* for GetAttributeByName() */
         
         bool
         c_overpaid(TupleTableSlot *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 name, 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 'PGROOT/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.
    
   
   
    Writing Code
    
     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 C 
     (including the use of pointers and the malloc memory manager)  
     before  trying to write C functions for 
     use with Postgres. While  it may 
     be possible to load functions written in languages other 
     than C into  Postgres,  
     this  is  often difficult  (when  it  is possible at all) 
     because other languages, such as FORTRAN 
     and Pascal often do not follow the same 
     calling convention
     as C.  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 C.
    
    
     C functions with base type arguments can be written in a
     straightforward fashion.  The C equivalents of built-in Postgres types
     are accessible in a C file if 
     PGROOT/src/backend/utils/builtins.h
     is included as a header file.  This can be achieved by having
     
#include <utils/builtins.h>
     
     at the top of the C source file.
    
    
     The  basic  rules  for building C functions 
     are as follows:
     
      
       
	Most of the header (include) files for 
	Postgres
	should      already      be     installed     in
	PGROOT/include  (see  Figure  2).
	You should always include
	
-I$PGROOT/include
	
	on  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$PGROOT/src/backend
-I$PGROOT/src/backend/include
-I$PGROOT/src/backend/port/<PORTNAME>
-I$PGROOT/src/backend/obj
	
	(where <PORTNAME> is the name of the port, e.g.,
	alpha or sparc).
       
      
      
       
	When allocating memory, use  the
	Postgres
	routines  palloc  and  pfree  instead of the 
	corresponding C library  routines  
	malloc  and  free.
	The  memory  allocated  by  palloc will be freed
	automatically at the end  of  each  transaction,
	preventing memory leaks.
       
      
      
       
	Always  zero  the bytes of your structures using
	memset or bzero.  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.
       
      
      
       
	    Most of the internal Postgres 
	types are declared in postgres.h,
	    so  it's a good 
	idea to always include that file as well.  Including 
	postgres.h will also include elog.h and palloc.h for you.
       
      
      
       
	Compiling and loading your object code  so  that
	it  can  be  dynamically  loaded  into  
	Postgres
	always requires special flags.
	See 
	for  a  detailed explanation of how to do it for
	your particular operating system.
       
      
     
    
   
  
  
   Function Overloading
   
    More than one function may be defined with the same name, as long as
    the arguments they take are different.  In other words, function names
    can be overloaded.
    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.
   
   
    Name Space Conflicts
    
     As of Postgres v6.6, the alternative
     form of the AS clause for the SQL
     CREATE FUNCTION command
     decouples the SQL function name from the function name in the C
     source code. This is now the preferred technique to accomplish
     function overloading.
    
    
     Pre-v6.6
     
      For functions written in C, the SQL name declared in
      CREATE FUNCTION
      must be exactly the same as the actual name of the function in the
      C code (hence it must be a legal C function name).
     
     
      There is a subtle implication of this restriction: while the
      dynamic loading routines in most operating systems are more than 
      happy to allow you to load any number of shared libraries that 
      contain conflicting (identically-named) function names, they may 
      in fact botch the load in interesting ways.  For example, if you
      define a dynamically-loaded function that happens to have the
      same name as a function built into Postgres, the DEC OSF/1 dynamic 
      loader causes Postgres to call the function within itself rather than 
      allowing Postgres to call your function.  Hence, if you want your
      function to be used on different architectures, we recommend that 
      you do not overload C function names.
     
     
      There is a clever trick to get around the problem just described.
      Since there is no problem overloading SQL functions, you can 
      define 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.
     
     
      Another solution is not to use dynamic loading, but to link your
      functions into the backend statically and declare them as INTERNAL
      functions.  Then, the functions must all have distinct C names but
      they can be declared with the same SQL names (as long as their
      argument types differ, of course).  This way avoids the overhead of
      an SQL wrapper function, at the cost of more effort to prepare a
      custom backend executable.  (This option is only available in version
      6.5 and later, since prior versions required internal functions to
      have the same name in SQL as in the C code.)