From: Tom Lane Date: Thu, 30 Dec 2004 03:13:56 +0000 (+0000) Subject: More updates and copy-editing. Rearrange order of sections a little bit X-Git-Tag: REL8_0_0RC3~6 X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=c3d583ddce9912afc68be755b04ec6acbd502329;p=postgresql More updates and copy-editing. Rearrange order of sections a little bit to put more widely useful info before less widely useful info. --- diff --git a/doc/src/sgml/extend.sgml b/doc/src/sgml/extend.sgml index 701943448f..352fb4bb3e 100644 --- a/doc/src/sgml/extend.sgml +++ b/doc/src/sgml/extend.sgml @@ -1,5 +1,5 @@ @@ -152,8 +152,8 @@ $PostgreSQL: pgsql/doc/src/sgml/extend.sgml,v 1.28 2004/06/07 04:04:47 tgl Exp $ Domains can be created using the SQL command - CREATE DOMAIN. Their creation and use is not - discussed in this chapter. + . + Their creation and use is not discussed in this chapter. @@ -221,7 +221,7 @@ $PostgreSQL: pgsql/doc/src/sgml/extend.sgml,v 1.28 2004/06/07 04:04:47 tgl Exp $ Thus, when more than one argument position is declared with a polymorphic type, the net effect is that only certain combinations of actual argument types are allowed. For example, a function declared as - foo(anyelement, anyelement) will take any two input values, + equal(anyelement, anyelement) will take any two input values, so long as they are of the same data type. diff --git a/doc/src/sgml/postgres.sgml b/doc/src/sgml/postgres.sgml index 831acc4371..36d58f4d89 100644 --- a/doc/src/sgml/postgres.sgml +++ b/doc/src/sgml/postgres.sgml @@ -1,5 +1,5 @@ PostgreSQL has - been understood. This part also describes the server-side + been understood. Later chapters in this part describe the server-side programming languages available in the PostgreSQL distribution as well as - general issues concerning server-side programming languages. This - information is only useful to readers that have read at least the - first few chapters of this part. + general issues concerning server-side programming languages. It + is essential to read at least the earlier sections of (covering functions) before diving into the + material about server-side programming languages. &extend; - &rules; &trigger; + &rules; &xplang; &plsql; diff --git a/doc/src/sgml/rules.sgml b/doc/src/sgml/rules.sgml index 3c9aea3c43..2b53c84c7b 100644 --- a/doc/src/sgml/rules.sgml +++ b/doc/src/sgml/rules.sgml @@ -1,4 +1,4 @@ - + The Rule System @@ -104,19 +104,19 @@ The range table is a list of relations that are used in the query. - In a SELECT statement these are the relations given after - the FROM key word. + In a SELECT statement these are the relations given after + the FROM key word. Every range table entry identifies a table or view and tells - by which name it is called in the other parts of the query. - In the query tree, the range table entries are referenced by - number rather than by name, so here it doesn't matter if there - are duplicate names as it would in an SQL - statement. This can happen after the range tables of rules - have been merged in. The examples in this chapter will not have - this situation. + by which name it is called in the other parts of the query. + In the query tree, the range table entries are referenced by + number rather than by name, so here it doesn't matter if there + are duplicate names as it would in an SQL + statement. This can happen after the range tables of rules + have been merged in. The examples in this chapter will not have + this situation. @@ -128,21 +128,21 @@ This is an index into the range table that identifies the - relation where the results of the query go. + relation where the results of the query go. - SELECT queries normally don't have a result - relation. The special case of a SELECT INTO is - mostly identical to a CREATE TABLE followed by a - INSERT ... SELECT and is not discussed - separately here. + SELECT queries normally don't have a result + relation. The special case of a SELECT INTO is + mostly identical to a CREATE TABLE followed by a + INSERT ... SELECT and is not discussed + separately here. For INSERT, UPDATE, and - DELETE commands, the result relation is the table - (or view!) where the changes take effect. + DELETE commands, the result relation is the table + (or view!) where the changes are to take effect. @@ -167,39 +167,39 @@ DELETE commands don't need a target list - because they don't produce any result. In fact, the planner will - add a special CTID entry to the empty target list, but - this is after the rule system and will be discussed later; for the - rule system, the target list is empty. + because they don't produce any result. In fact, the planner will + add a special CTID entry to the empty target list, but + this is after the rule system and will be discussed later; for the + rule system, the target list is empty. For INSERT commands, the target list describes - the new rows that should go into the result relation. It consists of the - expressions in the VALUES clause or the ones from the - SELECT clause in INSERT - ... SELECT. The first step of the rewrite process adds - target list entries for any columns that were not assigned to by - the original command but have defaults. Any remaining columns (with - neither a given value nor a default) will be filled in by the - planner with a constant null expression. + the new rows that should go into the result relation. It consists of the + expressions in the VALUES clause or the ones from the + SELECT clause in INSERT + ... SELECT. The first step of the rewrite process adds + target list entries for any columns that were not assigned to by + the original command but have defaults. Any remaining columns (with + neither a given value nor a default) will be filled in by the + planner with a constant null expression. For UPDATE commands, the target list - describes the new rows that should replace the old ones. In the - rule system, it contains just the expressions from the SET - column = expression part of the command. The planner will handle - missing columns by inserting expressions that copy the values from - the old row into the new one. And it will add the special - CTID entry just as for DELETE, too. + describes the new rows that should replace the old ones. In the + rule system, it contains just the expressions from the SET + column = expression part of the command. The planner will handle + missing columns by inserting expressions that copy the values from + the old row into the new one. And it will add the special + CTID entry just as for DELETE, too. Every entry in the target list contains an expression that can - be a constant value, a variable pointing to a column of one - of the relations in the range table, a parameter, or an expression - tree made of function calls, constants, variables, operators, etc. + be a constant value, a variable pointing to a column of one + of the relations in the range table, a parameter, or an expression + tree made of function calls, constants, variables, operators, etc. @@ -211,12 +211,12 @@ The query's qualification is an expression much like one of - those contained in the target list entries. The result value of - this expression is a Boolean that tells whether the operation - (INSERT, UPDATE, - DELETE, or SELECT) for the - final result row should be executed or not. It corresponds to the WHERE clause - of an SQL statement. + those contained in the target list entries. The result value of + this expression is a Boolean that tells whether the operation + (INSERT, UPDATE, + DELETE, or SELECT) for the + final result row should be executed or not. It corresponds to the WHERE clause + of an SQL statement. @@ -228,17 +228,17 @@ The query's join tree shows the structure of the FROM clause. - For a simple query like SELECT ... FROM a, b, c, the join tree is just - a list of the FROM items, because we are allowed to join them in - any order. But when JOIN expressions, particularly outer joins, - are used, we have to join in the order shown by the joins. - In that case, the join tree shows the structure of the JOIN expressions. The - restrictions associated with particular JOIN clauses (from ON or - USING expressions) are stored as qualification expressions attached - to those join-tree nodes. It turns out to be convenient to store - the top-level WHERE expression as a qualification attached to the - top-level join-tree item, too. So really the join tree represents - both the FROM and WHERE clauses of a SELECT. + For a simple query like SELECT ... FROM a, b, c, the join tree is just + a list of the FROM items, because we are allowed to join them in + any order. But when JOIN expressions, particularly outer joins, + are used, we have to join in the order shown by the joins. + In that case, the join tree shows the structure of the JOIN expressions. The + restrictions associated with particular JOIN clauses (from ON or + USING expressions) are stored as qualification expressions attached + to those join-tree nodes. It turns out to be convenient to store + the top-level WHERE expression as a qualification attached to the + top-level join-tree item, too. So really the join tree represents + both the FROM and WHERE clauses of a SELECT. @@ -250,10 +250,10 @@ The other parts of the query tree like the ORDER BY - clause aren't of interest here. The rule system - substitutes some entries there while applying rules, but that - doesn't have much to do with the fundamentals of the rule - system. + clause aren't of interest here. The rule system + substitutes some entries there while applying rules, but that + doesn't have much to do with the fundamentals of the rule + system. @@ -322,7 +322,7 @@ CREATE RULE "_RETURN" AS ON SELECT TO myview DO INSTEAD Currently, there can be only one action in an ON SELECT rule, and it must be an unconditional SELECT action that is INSTEAD. This restriction was required to make rules safe enough to open them for ordinary users, and - it restricts ON SELECT rules to real view rules. + it restricts ON SELECT rules to act like views. @@ -695,29 +695,29 @@ UPDATE t1 SET b = t2.b WHERE t1.a = t2.a; - - The range tables contain entries for the tables t1 and t2. - + + The range tables contain entries for the tables t1 and t2. + - - The target lists contain one variable that points to column - b of the range table entry for table t2. - + + The target lists contain one variable that points to column + b of the range table entry for table t2. + - - The qualification expressions compare the columns a of both - range-table entries for equality. - + + The qualification expressions compare the columns a of both + range-table entries for equality. + - - The join trees show a simple join between t1 and t2. - + + The join trees show a simple join between t1 and t2. + @@ -860,34 +860,34 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a; - - They are allowed to have no action. - - + + They are allowed to have no action. + + - - They can have multiple actions. - - + + They can have multiple actions. + + - - They can be INSTEAD or ALSO (default). - - + + They can be INSTEAD or ALSO (default). + + - - The pseudorelations NEW and OLD become useful. - - + + The pseudorelations NEW and OLD become useful. + + - - They can have rule qualifications. - - + + They can have rule qualifications. + + Second, they don't modify the query tree in place. Instead they @@ -1875,14 +1875,15 @@ GRANT SELECT ON phone_number TO secretary; - For the things that can be implemented by both, - it depends on the usage of the database, which is the best. + For the things that can be implemented by both, which is best + depends on the usage of the database. A trigger is fired for any affected row once. A rule manipulates - the query tree or generates an additional one. So if many + the query or generates an additional query. So if many rows are affected in one statement, a rule issuing one extra - command would usually do a better job than a trigger that is + command is likely to be faster than a trigger that is called for every single row and must execute its operations - many times. + many times. However, the trigger approach is conceptually far + simpler than the rule approach, and is easier for novices to get right. diff --git a/doc/src/sgml/trigger.sgml b/doc/src/sgml/trigger.sgml index fdecf5483b..f7fa39b802 100644 --- a/doc/src/sgml/trigger.sgml +++ b/doc/src/sgml/trigger.sgml @@ -1,5 +1,5 @@ @@ -58,6 +58,15 @@ $PostgreSQL: pgsql/doc/src/sgml/trigger.sgml,v 1.38 2004/12/13 18:05:09 petere E respectively. + + Statement-level before triggers naturally fire before the + statement starts to do anything, while statement-level after + triggers fire at the very end of the statement. Row-level before + triggers fire immediately before a particular row is operated on, + while row-level after triggers fire at the end of the statement + (but before any statement-level after triggers). + + Trigger functions invoked by per-statement triggers should always return NULL. Trigger functions invoked by per-row @@ -110,6 +119,21 @@ $PostgreSQL: pgsql/doc/src/sgml/trigger.sgml,v 1.38 2004/12/13 18:05:09 petere E triggers are not fired. + + Typically, row before triggers are used for checking or + modifying the data that will be inserted or updated. For example, + a before trigger might be used to insert the current time into a + timestamp column, or to check that two elements of the row are + consistent. Row after triggers are most sensibly + used to propagate the updates to other tables, or make consistency + checks against other tables. The reason for this division of labor is + that an after trigger can be certain it is seeing the final value of the + row, while a before trigger cannot; there might be other before triggers + firing after it. If you have no specific reason to make a trigger before + or after, the before case is more efficient, since the information about + the operation doesn't have to be saved until end of statement. + + If a trigger function executes SQL commands then these commands may fire triggers again. This is known as cascading @@ -140,6 +164,20 @@ $PostgreSQL: pgsql/doc/src/sgml/trigger.sgml,v 1.38 2004/12/13 18:05:09 petere E trigger. + + Each programming language that supports triggers has its own method + for making the trigger input data available to the trigger function. + This input data includes the type of trigger event (e.g., + INSERT or UPDATE) as well as any + arguments that were listed in CREATE TRIGGER. + For a row-level trigger, the input data also includes the + NEW row for INSERT and + UPDATE triggers, and/or the OLD row + for UPDATE and DELETE triggers. + Statement-level triggers do not currently have any way to examine the + individual row(s) modified by the statement. + + @@ -277,73 +315,73 @@ typedef struct TriggerData tg_event - Describes the event for which the function is called. You may use the - following macros to examine tg_event: - - - - TRIGGER_FIRED_BEFORE(tg_event) - - - Returns true if the trigger fired before the operation. - - - - - - TRIGGER_FIRED_AFTER(tg_event) - - - Returns true if the trigger fired after the operation. - - - - - - TRIGGER_FIRED_FOR_ROW(tg_event) - - - Returns true if the trigger fired for a row-level event. - - - - - - TRIGGER_FIRED_FOR_STATEMENT(tg_event) - - - Returns true if the trigger fired for a statement-level event. - - - - - - TRIGGER_FIRED_BY_INSERT(tg_event) - - - Returns true if the trigger was fired by an INSERT command. - - - - - - TRIGGER_FIRED_BY_UPDATE(tg_event) - - - Returns true if the trigger was fired by an UPDATE command. - - - - - - TRIGGER_FIRED_BY_DELETE(tg_event) - - - Returns true if the trigger was fired by a DELETE command. - - - - + Describes the event for which the function is called. You may use the + following macros to examine tg_event: + + + + TRIGGER_FIRED_BEFORE(tg_event) + + + Returns true if the trigger fired before the operation. + + + + + + TRIGGER_FIRED_AFTER(tg_event) + + + Returns true if the trigger fired after the operation. + + + + + + TRIGGER_FIRED_FOR_ROW(tg_event) + + + Returns true if the trigger fired for a row-level event. + + + + + + TRIGGER_FIRED_FOR_STATEMENT(tg_event) + + + Returns true if the trigger fired for a statement-level event. + + + + + + TRIGGER_FIRED_BY_INSERT(tg_event) + + + Returns true if the trigger was fired by an INSERT command. + + + + + + TRIGGER_FIRED_BY_UPDATE(tg_event) + + + Returns true if the trigger was fired by an UPDATE command. + + + + + + TRIGGER_FIRED_BY_DELETE(tg_event) + + + Returns true if the trigger was fired by a DELETE command. + + + + @@ -352,15 +390,15 @@ typedef struct TriggerData tg_relation - A pointer to a structure describing the relation that the trigger fired for. - Look at utils/rel.h for details about - this structure. The most interesting things are - tg_relation->rd_att (descriptor of the relation - tuples) and tg_relation->rd_rel->relname - (relation name; the type is not char* but - NameData; use - SPI_getrelname(tg_relation) to get a char* if you - need a copy of the name). + A pointer to a structure describing the relation that the trigger fired for. + Look at utils/rel.h for details about + this structure. The most interesting things are + tg_relation->rd_att (descriptor of the relation + tuples) and tg_relation->rd_rel->relname + (relation name; the type is not char* but + NameData; use + SPI_getrelname(tg_relation) to get a char* if you + need a copy of the name). @@ -369,13 +407,13 @@ typedef struct TriggerData tg_trigtuple - A pointer to the row for which the trigger was fired. This is - the row being inserted, updated, or deleted. If this trigger - was fired for an INSERT or - DELETE then this is what you should return - to from the function if you don't want to replace the row with - a different one (in the case of INSERT) or - skip the operation. + A pointer to the row for which the trigger was fired. This is + the row being inserted, updated, or deleted. If this trigger + was fired for an INSERT or + DELETE then this is what you should return + from the function if you don't want to replace the row with + a different one (in the case of INSERT) or + skip the operation. @@ -384,13 +422,13 @@ typedef struct TriggerData tg_newtuple - A pointer to the new version of the row, if the trigger was - fired for an UPDATE, and NULL if - it is for an INSERT or a - DELETE. This is what you have to return - from the function if the event is an UPDATE - and you don't want to replace this row by a different one or - skip the operation. + A pointer to the new version of the row, if the trigger was + fired for an UPDATE, and NULL if + it is for an INSERT or a + DELETE. This is what you have to return + from the function if the event is an UPDATE + and you don't want to replace this row by a different one or + skip the operation. @@ -399,8 +437,8 @@ typedef struct TriggerData tg_trigger - A pointer to a structure of type Trigger, - defined in utils/rel.h: + A pointer to a structure of type Trigger, + defined in utils/rel.h: typedef struct Trigger diff --git a/doc/src/sgml/xfunc.sgml b/doc/src/sgml/xfunc.sgml index 4a2dac06e0..649fd0e4da 100644 --- a/doc/src/sgml/xfunc.sgml +++ b/doc/src/sgml/xfunc.sgml @@ -1,5 +1,5 @@ @@ -24,7 +24,7 @@ $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.90 2004/12/13 18:05:09 petere Exp procedural language functions (functions written in, for - example, PL/Tcl or PL/pgSQL) + example, PL/pgSQL or PL/Tcl) () @@ -44,9 +44,10 @@ $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.90 2004/12/13 18:05:09 petere Exp Every kind of function can take base types, composite types, or - combinations of these as arguments (parameters). In addition, + combinations of these as arguments (parameters). In addition, every kind of function can return a base type or - a composite type. + a composite type. Functions may also be defined to return + sets of base or composite values. @@ -64,7 +65,8 @@ $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.90 2004/12/13 18:05:09 petere Exp Throughout this chapter, it can be useful to look at the reference - page of the command to + page of the command to understand the examples better. Some examples from this chapter can be found in funcs.sql and funcs.c in the src/tutorial @@ -141,7 +143,7 @@ CREATE FUNCTION one() RETURNS integer AS $$ SELECT 1 AS result; $$ LANGUAGE SQL; --- Alternative syntax: +-- Alternative syntax for string literal: CREATE FUNCTION one() RETURNS integer AS ' SELECT 1 AS result; ' LANGUAGE SQL; @@ -335,16 +337,16 @@ $$ LANGUAGE SQL; - The select list order in the query must be exactly the same as - that in which the columns appear in the table associated - with the composite type. (Naming the columns, as we did above, - is irrelevant to the system.) + The select list order in the query must be exactly the same as + that in which the columns appear in the table associated + with the composite type. (Naming the columns, as we did above, + is irrelevant to the system.) - You must typecast the expressions to match the - definition of the composite type, or you will get errors like this: + You must typecast the expressions to match the + definition of the composite type, or you will get errors like this: ERROR: function declared to return emp returns varchar instead of text at column 1 @@ -356,15 +358,9 @@ ERROR: function declared to return emp returns varchar instead of text at colum - A function that returns a row (composite type) can be used as a table - function, as described below. It can also be called in the context - of an SQL expression, but only when you - extract a single attribute out of the row or pass the entire row into - another function that accepts the same composite type. - - - - This is an example of extracting an attribute out of a row type: + When you call a function that returns a row (composite type) in a + SQL expression, you might want only one field (attribute) from its + result. You can do that with syntax like this: SELECT (new_emp()).name; @@ -374,11 +370,14 @@ SELECT (new_emp()).name; None - We need the extra parentheses to keep the parser from getting confused: + The extra parentheses are needed to keep the parser from getting + confused. If you try to do it without them, you get something like this: SELECT new_emp().name; ERROR: syntax error at or near "." at character 17 +LINE 1: SELECT new_emp().name; + ^ @@ -412,9 +411,8 @@ SELECT name(emp) AS youngster - The other way to use a function returning a row result is to declare a - second function accepting a row type argument and pass the - result of the first function to it: + Another way to use a function returning a row result is to pass the + result to another function that accepts the correct row type as input: CREATE FUNCTION getname(emp) RETURNS text AS $$ @@ -428,6 +426,11 @@ SELECT getname(new_emp()); (1 row) + + + Another way to use a function that returns a composite type is to + call it as a table function, as described below. + @@ -469,7 +472,7 @@ SELECT *, upper(fooname) FROM getfoo(1) AS t1; Note that we only got one row out of the function. This is because - we did not use SETOF. This is described in the next section. + we did not use SETOF. That is described in the next section. @@ -598,7 +601,7 @@ ERROR: could not determine "anyarray"/"anyelement" type because input has type - It is permitted to have polymorphic arguments with a deterministic + It is permitted to have polymorphic arguments with a fixed return type, but the converse is not. For example: CREATE FUNCTION is_greater(anyelement, anyelement) RETURNS boolean AS $$ @@ -621,6 +624,201 @@ DETAIL: A function returning "anyarray" or "anyelement" must have at least one + + Function Overloading + + + overloading + functions + + + + More than one function may be defined with the same SQL name, so long + as the arguments they take are different. In other words, + function names can be overloaded. 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. + + + + When creating a family of overloaded functions, one should be + careful not to create ambiguities. For instance, given the + functions + +CREATE FUNCTION test(int, real) RETURNS ... +CREATE FUNCTION test(smallint, double precision) RETURNS ... + + it is not immediately clear which function would be called with + some trivial input like test(1, 1.5). The + currently implemented resolution rules are described in + , but it is unwise to design a system that subtly + relies on this behavior. + + + + A function that takes a single argument of a composite type should + generally not have the same name as any attribute (field) of that type. + Recall that attribute(table) is considered equivalent + to table.attribute. In the case that there is an + ambiguity between a function on a composite type and an attribute of + the composite type, the attribute will always be used. It is possible + to override that choice by schema-qualifying the function name + (that is, schema.func(table)) but it's better to + avoid the problem by not choosing conflicting names. + + + + 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 + AS clause for the SQL CREATE + FUNCTION command decouples the SQL function name from + the function name in the C source code. For instance, + +CREATE FUNCTION test(int) RETURNS int + AS 'filename', 'test_1arg' + LANGUAGE C; +CREATE FUNCTION test(int, int) RETURNS int + AS 'filename', 'test_2arg' + LANGUAGE C; + + The names of the C functions here reflect one of many possible conventions. + + + + + Function Volatility Categories + + + volatility + functions + + + + Every function has a volatility classification, with + the possibilities being VOLATILE, STABLE, or + IMMUTABLE. VOLATILE is the default if the + CREATE FUNCTION command does not specify a category. + The volatility category is a promise to the optimizer about the behavior + of the function: + + + + + A VOLATILE function can do anything, including modifying + the database. It can return different results on successive calls with + the same arguments. The optimizer makes no assumptions about the + behavior of such functions. A query using a volatile function will + re-evaluate the function at every row where its value is needed. + + + + + A STABLE function cannot modify the database and is + guaranteed to return the same results given the same arguments + for all calls within a single surrounding query. This category + allows the optimizer to optimize away multiple calls of the function + within a single query. In particular, it is safe to use an expression + containing such a function in an index scan condition. (Since an + index scan will evaluate the comparison value only once, not once at + each row, it is not valid to use a VOLATILE function in + an index scan condition.) + + + + + An IMMUTABLE function cannot modify the database and is + guaranteed to return the same results given the same arguments forever. + This category allows the optimizer to pre-evaluate the function when + a query calls it with constant arguments. For example, a query like + SELECT ... WHERE x = 2 + 2 can be simplified on sight to + SELECT ... WHERE x = 4, because the function underlying + the integer addition operator is marked IMMUTABLE. + + + + + + + For best optimization results, you should label your functions with the + strictest volatility category that is valid for them. + + + + Any function with side-effects must be labeled + VOLATILE, so that calls to it cannot be optimized away. + Even a function with no side-effects needs to be labeled + VOLATILE if its value can change within a single query; + some examples are random(), currval(), + timeofday(). + + + + There is relatively little difference between STABLE and + IMMUTABLE categories when considering simple interactive + queries that are planned and immediately executed: it doesn't matter + a lot whether a function is executed once during planning or once during + query execution startup. But there is a big difference if the plan is + saved and reused later. Labeling a function IMMUTABLE when + it really isn't may allow it to be prematurely folded to a constant during + planning, resulting in a stale value being re-used during subsequent uses + of the plan. This is a hazard when using prepared statements or when + using function languages that cache plans (such as + PL/pgSQL). + + + + Because of the snapshotting behavior of MVCC (see ) + a function containing only SELECT commands can safely be + marked STABLE, even if it selects from tables that might be + undergoing modifications by concurrent queries. + PostgreSQL will execute a STABLE + function using the snapshot established for the calling query, and so it + will see a fixed view of the database throughout that query. + Also note + that the current_timestamp family of functions qualify + as stable, since their values do not change within a transaction. + + + + The same snapshotting behavior is used for SELECT commands + within IMMUTABLE functions. It is generally unwise to select + from database tables within an IMMUTABLE function at all, + since the immutability will be broken if the table contents ever change. + However, PostgreSQL does not enforce that you + do not do that. + + + + A common error is to label a function IMMUTABLE when its + results depend on a configuration parameter. For example, a function + that manipulates timestamps might well have results that depend on the + setting. For safety, such functions should + be labeled STABLE instead. + + + + + Before PostgreSQL release 8.0, the requirement + that STABLE and IMMUTABLE functions cannot modify + the database was not enforced by the system. Release 8.0 enforces it + by requiring SQL functions and procedural language functions of these + categories to contain no SQL commands other than SELECT. + (This is not a completely bulletproof test, since such functions could + still call VOLATILE functions that modify the database. + If you do that, you will find that the STABLE or + IMMUTABLE function does not notice the database changes + applied by the called function.) + + + + Procedural Language Functions @@ -754,7 +952,7 @@ CREATE FUNCTION square_root(double precision) RETURNS double precision If the name starts with the string $libdir, that part is replaced by the PostgreSQL package - library directory + library directory name, which is determined at build time.$libdir @@ -864,17 +1062,17 @@ CREATE FUNCTION square_root(double precision) RETURNS double precision - pass by value, fixed-length + pass by value, fixed-length - pass by reference, fixed-length + pass by reference, fixed-length - pass by reference, variable-length + pass by reference, variable-length @@ -993,169 +1191,169 @@ memcpy(destination->data, buffer, 40); Equivalent C Types for Built-In SQL Types - - - SQL Type - - - C Type - - - Defined In - - + + + SQL Type + + + C Type + + + Defined In + + - - abstime - AbsoluteTime - utils/nabstime.h - - - boolean - bool - postgres.h (maybe compiler built-in) - - - box - BOX* - utils/geo_decls.h - - - bytea - bytea* - postgres.h - - - "char" - char - (compiler built-in) - - - character - BpChar* - postgres.h - - - cid - CommandId - postgres.h - - - date - DateADT - utils/date.h - - - smallint (int2) - int2 or int16 - postgres.h - - - int2vector - int2vector* - postgres.h - - - integer (int4) - int4 or int32 - postgres.h - - - real (float4) - float4* - postgres.h - - - double precision (float8) - float8* - postgres.h - - - interval - Interval* - utils/timestamp.h - - - lseg - LSEG* - utils/geo_decls.h - - - name - Name - postgres.h - - - oid - Oid - postgres.h - - - oidvector - oidvector* - postgres.h - - - path - PATH* - utils/geo_decls.h - - - point - POINT* - utils/geo_decls.h - - - regproc - regproc - postgres.h - - - reltime - RelativeTime - utils/nabstime.h - - - text - text* - postgres.h - - - tid - ItemPointer - storage/itemptr.h - - - time - TimeADT - utils/date.h - - - time with time zone - TimeTzADT - utils/date.h - - - timestamp - Timestamp* - utils/timestamp.h - - - tinterval - TimeInterval - utils/nabstime.h - - - varchar - VarChar* - postgres.h - - - xid - TransactionId - postgres.h - + + abstime + AbsoluteTime + utils/nabstime.h + + + boolean + bool + postgres.h (maybe compiler built-in) + + + box + BOX* + utils/geo_decls.h + + + bytea + bytea* + postgres.h + + + "char" + char + (compiler built-in) + + + character + BpChar* + postgres.h + + + cid + CommandId + postgres.h + + + date + DateADT + utils/date.h + + + smallint (int2) + int2 or int16 + postgres.h + + + int2vector + int2vector* + postgres.h + + + integer (int4) + int4 or int32 + postgres.h + + + real (float4) + float4* + postgres.h + + + double precision (float8) + float8* + postgres.h + + + interval + Interval* + utils/timestamp.h + + + lseg + LSEG* + utils/geo_decls.h + + + name + Name + postgres.h + + + oid + Oid + postgres.h + + + oidvector + oidvector* + postgres.h + + + path + PATH* + utils/geo_decls.h + + + point + POINT* + utils/geo_decls.h + + + regproc + regproc + postgres.h + + + reltime + RelativeTime + utils/nabstime.h + + + text + text* + postgres.h + + + tid + ItemPointer + storage/itemptr.h + + + time + TimeADT + utils/date.h + + + time with time zone + TimeTzADT + utils/date.h + + + timestamp + Timestamp* + utils/timestamp.h + + + tinterval + TimeInterval + utils/nabstime.h + + + varchar + VarChar* + postgres.h + + + xid + TransactionId + postgres.h + @@ -1567,9 +1765,9 @@ concat_text(PG_FUNCTION_ARGS) Always zero the bytes of your structures using - memset. Without this, it's difficult to - support hash indexes or hash joins, as you must pick out only - the significant bits of your data structure to compute a hash. + memset. Without this, it's difficult to + support hash indexes or hash joins, as you must pick out only + the significant bits of your data structure to compute a hash. Even if you initialize all fields of your structure, there may be alignment padding (holes in the structure) that may contain garbage values. @@ -1618,7 +1816,7 @@ concat_text(PG_FUNCTION_ARGS) &dfunc; - Extension build infrastructure + Extension Building Infrastructure pgxs @@ -1868,14 +2066,14 @@ c_overpaid(PG_FUNCTION_ARGS) HeapTupleHeader t = PG_GETARG_HEAPTUPLEHEADER(0); int32 limit = PG_GETARG_INT32(1); bool isnull; - int32 salary; + Datum salary; - salary = DatumGetInt32(GetAttributeByName(t, "salary", &isnull)); + salary = 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); + PG_RETURN_BOOL(DatumGetInt32(salary) > limit); } @@ -1890,7 +2088,10 @@ c_overpaid(PG_FUNCTION_ARGS) return parameter that tells whether the attribute is null. GetAttributeByName returns a Datum value that you can convert to the proper data type by using the - appropriate DatumGetXXX() macro. + appropriate DatumGetXXX() + macro. Note that the return value is meaningless if the null flag is + set; always check the null flag before trying to do anything with the + result. @@ -2222,7 +2423,7 @@ testpassbyval(PG_FUNCTION_ARGS) /* stuff done only on the first call of the function */ if (SRF_IS_FIRSTCALL()) { - MemoryContext oldcontext; + MemoryContext oldcontext; /* create a function context for cross-call persistence */ funcctx = SRF_FIRSTCALL_INIT(); @@ -2393,196 +2594,6 @@ CREATE FUNCTION make_array(anyelement) RETURNS anyarray - - Function Overloading - - - overloading - functions - - - - More than one function may be defined with the same SQL name, so long - as the arguments they take are different. In other words, - function names can be overloaded. 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. - - - - When creating a family of overloaded functions, one should be - careful not to create ambiguities. For instance, given the - functions - -CREATE FUNCTION test(int, real) RETURNS ... -CREATE FUNCTION test(smallint, double precision) RETURNS ... - - it is not immediately clear which function would be called with - some trivial input like test(1, 1.5). The - currently implemented resolution rules are described in - , but it is unwise to design a system that subtly - relies on this behavior. - - - - A function that takes a single argument of a composite type should - generally not have the same name as any attribute (field) of that type. - Recall that attribute(table) is considered equivalent - to table.attribute. In the case that there is an - ambiguity between a function on a composite type and an attribute of - the composite type, the attribute will always be used. It is possible - to override that choice by schema-qualifying the function name - (that is, schema.func(table)) but it's better to - avoid the problem by not choosing conflicting names. - - - - 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 - AS clause for the SQL CREATE - FUNCTION command decouples the SQL function name from - the function name in the C source code. For instance, - -CREATE FUNCTION test(int) RETURNS int - AS 'filename', 'test_1arg' - LANGUAGE C; -CREATE FUNCTION test(int, int) RETURNS int - AS 'filename', 'test_2arg' - LANGUAGE C; - - The names of the C functions here reflect one of many possible conventions. - - - - - Function Volatility Categories - - - volatility - functions - - - - Every function has a volatility classification, with - the possibilities being VOLATILE, STABLE, or - IMMUTABLE. VOLATILE is the default if the - CREATE FUNCTION command does not specify a category. - The volatility category is a promise to the optimizer about the behavior - of the function: - - - - - A VOLATILE function can do anything, including modifying - the database. It can return different results on successive calls with - the same arguments. The optimizer makes no assumptions about the - behavior of such functions. A query using a volatile function will - re-evaluate the function at every row where its value is needed. - - - - - A STABLE function cannot modify the database and is - guaranteed to return the same results given the same arguments - for all calls within a single surrounding query. This category - allows the optimizer to optimize away multiple calls of the function - within a single query. In particular, it is safe to use an expression - containing such a function in an index scan condition. (Since an - index scan will evaluate the comparison value only once, not once at - each row, it is not valid to use a VOLATILE function in - an index scan condition.) - - - - - An IMMUTABLE function cannot modify the database and is - guaranteed to return the same results given the same arguments forever. - This category allows the optimizer to pre-evaluate the function when - a query calls it with constant arguments. For example, a query like - SELECT ... WHERE x = 2 + 2 can be simplified on sight to - SELECT ... WHERE x = 4, because the function underlying - the integer addition operator is marked IMMUTABLE. - - - - - - - For best optimization results, you should label your functions with the - strictest volatility category that is valid for them. - - - - Any function with side-effects must be labeled - VOLATILE, so that calls to it cannot be optimized away. - Even a function with no side-effects needs to be labeled - VOLATILE if its value can change within a single query; - some examples are random(), currval(), - timeofday(). - - - - There is relatively little difference between STABLE and - IMMUTABLE categories when considering simple interactive - queries that are planned and immediately executed: it doesn't matter - a lot whether a function is executed once during planning or once during - query execution startup. But there is a big difference if the plan is - saved and reused later. Labeling a function IMMUTABLE when - it really isn't may allow it to be prematurely folded to a constant during - planning, resulting in a stale value being re-used during subsequent uses - of the plan. This is a hazard when using prepared statements or when - using function languages that cache plans (such as - PL/pgSQL). - - - - Because of the snapshotting behavior of MVCC (see ) - a function containing only SELECT commands can safely be - marked STABLE, even if it selects from tables that might be - undergoing modifications by concurrent queries. - PostgreSQL will execute a STABLE - function using the snapshot established for the calling query, and so it - will see a fixed view of the database throughout that query. - Also note - that the current_timestamp family of functions qualify - as stable, since their values do not change within a transaction. - - - - The same snapshotting behavior is used for SELECT commands - within IMMUTABLE functions. It is generally unwise to select - from database tables within an IMMUTABLE function at all, - since the immutability will be broken if the table contents ever change. - However, PostgreSQL does not enforce that you - do not do that. - - - - A common error is to label a function IMMUTABLE when its - results depend on a configuration parameter. For example, a function - that manipulates timestamps might well have results that depend on the - setting. For safety, such functions should - be labeled STABLE instead. - - - - - Before PostgreSQL release 8.0, the requirement - that STABLE and IMMUTABLE functions cannot modify - the database was not enforced by the system. Release 8.0 enforces it - by requiring SQL functions and procedural language functions of these - categories to contain no SQL commands other than SELECT. - - - - @@ -29,10 +29,16 @@ $PostgreSQL: pgsql/doc/src/sgml/xplang.sgml,v 1.26 2003/11/29 19:51:38 pgsql Exp Writing a handler for a new procedural language is described in . Several procedural languages are - available in the standard PostgreSQL + available in the core PostgreSQL distribution, which can serve as examples. + + There are additional procedural languages available that are not + included in the core distribution. + has information about finding them. + + Installing Procedural Languages