📄 xfunc.sgml
字号:
<Chapter Id="xfunc"><Title>Extending <Acronym>SQL</Acronym>: Functions</Title><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. <ProductName>Postgres</ProductName> <Acronym>SQL</Acronym> provides two types of functions: query language functions (functions written in <Acronym>SQL</Acronym> and programming language functions (functions written in a compiled programming language such as <Acronym>C</Acronym>.) Either kind of function can take a base type, a composite type or some combination as arguments (parameters). In addition, both kinds of functions can return a base type or a composite type. It's easier 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>.</Para><Sect1><Title>Query Language (<Acronym>SQL</Acronym>) Functions</Title><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 <Acronym>int4</Acronym>: <ProgramListing> CREATE FUNCTION one() RETURNS int4 AS 'SELECT 1 as RESULT' LANGUAGE 'sql'; SELECT one() AS answer; +-------+ |answer | +-------+ |1 | +-------+</ProgramListing></Para><Para> 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.</Para><Para> It's 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 $1 and $2. <ProgramListing> CREATE FUNCTION add_em(int4, int4) RETURNS int4 AS 'SELECT $1 + $2;' LANGUAGE 'sql'; SELECT add_em(1, 2) AS answer; +-------+ |answer | +-------+ |3 | +-------+</ProgramListing></Para></sect2><Sect2><Title><Acronym>SQL</Acronym> Functions on Composite Types</Title><Para> 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. <ProgramListing> 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 | +-----+-------+</ProgramListing></para><Para> 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. <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; +----------+ |youngster | +----------+ |Sam | +----------+</ProgramListing></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 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: <ProgramListing> 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';</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 CREATE TABLE statement (or when you execute a .* query).</Para> </ListItem> <ListItem><Para>You must typecast the expressions (using ::) very carefully or you will see the following error: <ProgramListing> WARN::function declared to return type EMP does not retrieve (EMP.*)</ProgramListing></Para> </ListItem><ListItem><Para>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.<ProgramListing> SELECT name(new_emp()) AS nobody; +-------+ |nobody | +-------+ |None | +-------+</ProgramListing></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. <ProgramListing> SELECT new_emp().name AS nobody; WARN:parser: syntax error at or near "."</ProgramListing></Para> </ListItem></ItemizedList></para> <Para> Any collection of commands in the <Acronym>SQL</Acronym> query language can be packaged together and defined as a function. The commands can include updates (i.e., <Acronym>insert</Acronym>, <Acronym>update</Acronym> and <Acronym>delete</Acronym>) as well as <Acronym>select</Acronym> queries. However, the final command must be a <Acronym>select</Acronym> that returns whatever is specified as the function's returntype. <ProgramListing> 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 | +--+ </ProgramListing></Para></sect2></sect1><Sect1><Title>Programming Language Functions</Title><Sect2><Title>Programming Language Functions on Base Types</Title><Para> Internally, <ProductName>Postgres</ProductName> 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 <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 (even if your computer supports by-value types of other sizes). <ProductName>Postgres</ProductName> 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 <Acronym>long</Acronym> type is dangerous because it is 4 bytes on some machines and 8 bytes on others, whereas <Acronym>int</Acronym> type is 4 bytes on most <Acronym>UNIX</Acronym> machines (though not on most personal computers). A reasonable implementation of the <Acronym>int4</Acronym> type on <Acronym>UNIX</Acronym> machines might be: <ProgramListing> /* 4-byte integer, passed by value */ typedef int int4;</ProgramListing></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>Postgres</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. Finally, all variable-length types must also be passed
⌨️ 快捷键说明
复制代码
Ctrl + C
搜索代码
Ctrl + F
全屏模式
F11
切换主题
Ctrl + Shift + D
显示快捷键
?
增大字号
Ctrl + =
减小字号
Ctrl + -