diff options
Diffstat (limited to 'doc/src')
26 files changed, 1222 insertions, 48 deletions
diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml index da881a77371..3f02202cafb 100644 --- a/doc/src/sgml/catalogs.sgml +++ b/doc/src/sgml/catalogs.sgml @@ -5241,7 +5241,7 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l <entry><structfield>prorettype</structfield></entry> <entry><type>oid</type></entry> <entry><literal><link linkend="catalog-pg-type"><structname>pg_type</structname></link>.oid</literal></entry> - <entry>Data type of the return value</entry> + <entry>Data type of the return value, or null for a procedure</entry> </row> <row> diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index e6f50ec819b..9f583266de9 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -3947,7 +3947,7 @@ EXPLAIN SELECT count(*) FROM measurement WHERE logdate >= DATE '2008-01-01'; <listitem> <para> - Functions and operators + Functions, procedures, and operators </para> </listitem> diff --git a/doc/src/sgml/ecpg.sgml b/doc/src/sgml/ecpg.sgml index d1872c1a5c6..5a8d1f1b95b 100644 --- a/doc/src/sgml/ecpg.sgml +++ b/doc/src/sgml/ecpg.sgml @@ -4778,7 +4778,9 @@ EXEC SQL WHENEVER <replaceable>condition</replaceable> <replaceable>action</repl <term><literal>DO <replaceable>name</replaceable> (<replaceable>args</replaceable>)</literal></term> <listitem> <para> - Call the specified C functions with the specified arguments. + Call the specified C functions with the specified arguments. (This + use is different from the meaning of <literal>CALL</literal> + and <literal>DO</literal> in the normal PostgreSQL grammar.) </para> </listitem> </varlistentry> diff --git a/doc/src/sgml/information_schema.sgml b/doc/src/sgml/information_schema.sgml index 99b0ea8519e..0faa72f1d3f 100644 --- a/doc/src/sgml/information_schema.sgml +++ b/doc/src/sgml/information_schema.sgml @@ -3972,8 +3972,8 @@ ORDER BY c.ordinal_position; <title><literal>routines</literal></title> <para> - The view <literal>routines</literal> contains all functions in the - current database. Only those functions are shown that the current + The view <literal>routines</literal> contains all functions and procedures in the + current database. Only those functions and procedures are shown that the current user has access to (by way of being the owner or having some privilege). </para> @@ -4037,8 +4037,8 @@ ORDER BY c.ordinal_position; <entry><literal>routine_type</literal></entry> <entry><type>character_data</type></entry> <entry> - Always <literal>FUNCTION</literal> (In the future there might - be other types of routines.) + <literal>FUNCTION</literal> for a + function, <literal>PROCEDURE</literal> for a procedure </entry> </row> @@ -4087,7 +4087,7 @@ ORDER BY c.ordinal_position; the view <literal>element_types</literal>), else <literal>USER-DEFINED</literal> (in that case, the type is identified in <literal>type_udt_name</literal> and associated - columns). + columns). Null for a procedure. </entry> </row> @@ -4180,7 +4180,7 @@ ORDER BY c.ordinal_position; <entry><type>sql_identifier</type></entry> <entry> Name of the database that the return data type of the function - is defined in (always the current database) + is defined in (always the current database). Null for a procedure. </entry> </row> @@ -4189,7 +4189,7 @@ ORDER BY c.ordinal_position; <entry><type>sql_identifier</type></entry> <entry> Name of the schema that the return data type of the function is - defined in + defined in. Null for a procedure. </entry> </row> @@ -4197,7 +4197,7 @@ ORDER BY c.ordinal_position; <entry><literal>type_udt_name</literal></entry> <entry><type>sql_identifier</type></entry> <entry> - Name of the return data type of the function + Name of the return data type of the function. Null for a procedure. </entry> </row> @@ -4314,7 +4314,7 @@ ORDER BY c.ordinal_position; <entry> If the function automatically returns null if any of its arguments are null, then <literal>YES</literal>, else - <literal>NO</literal>. + <literal>NO</literal>. Null for a procedure. </entry> </row> diff --git a/doc/src/sgml/plperl.sgml b/doc/src/sgml/plperl.sgml index 33e39d85e40..100162dead5 100644 --- a/doc/src/sgml/plperl.sgml +++ b/doc/src/sgml/plperl.sgml @@ -68,6 +68,10 @@ $$ LANGUAGE plperl; </para> <para> + In a PL/Perl procedure, any return value from the Perl code is ignored. + </para> + + <para> PL/Perl also supports anonymous code blocks called with the <xref linkend="sql-do"/> statement: diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml index 6d14b344487..7d23ed437e2 100644 --- a/doc/src/sgml/plpgsql.sgml +++ b/doc/src/sgml/plpgsql.sgml @@ -156,7 +156,8 @@ <para> Finally, a <application>PL/pgSQL</application> function can be declared to return - <type>void</type> if it has no useful return value. + <type>void</type> if it has no useful return value. (Alternatively, it + could be written as a procedure in that case.) </para> <para> @@ -1865,6 +1866,18 @@ SELECT * FROM get_available_flightid(CURRENT_DATE); </sect3> </sect2> + <sect2 id="plpgsql-statements-returning-procedure"> + <title>Returning From a Procedure</title> + + <para> + A procedure does not have a return value. A procedure can therefore end + without a <command>RETURN</command> statement. If + a <command>RETURN</command> statement is desired to exit the code early, + then <symbol>NULL</symbol> must be returned. Returning any other value + will result in an error. + </para> + </sect2> + <sect2 id="plpgsql-conditionals"> <title>Conditionals</title> @@ -5244,7 +5257,7 @@ show errors; <para> Here is how this function would end up in <productname>PostgreSQL</productname>: <programlisting> -CREATE OR REPLACE FUNCTION cs_update_referrer_type_proc() RETURNS void AS $func$ +CREATE OR REPLACE PROCEDURE cs_update_referrer_type_proc() AS $func$ DECLARE referrer_keys CURSOR IS SELECT * FROM cs_referrer_keys diff --git a/doc/src/sgml/plpython.sgml b/doc/src/sgml/plpython.sgml index ec5f671632d..0dbeee1fa2e 100644 --- a/doc/src/sgml/plpython.sgml +++ b/doc/src/sgml/plpython.sgml @@ -207,7 +207,11 @@ $$ LANGUAGE plpythonu; <literal>yield</literal> (in case of a result-set statement). If you do not provide a return value, Python returns the default <symbol>None</symbol>. <application>PL/Python</application> translates - Python's <symbol>None</symbol> into the SQL null value. + Python's <symbol>None</symbol> into the SQL null value. In a procedure, + the result from the Python code must be <symbol>None</symbol> (typically + achieved by ending the procedure without a <literal>return</literal> + statement or by using a <literal>return</literal> statement without + argument); otherwise, an error will be raised. </para> <para> diff --git a/doc/src/sgml/pltcl.sgml b/doc/src/sgml/pltcl.sgml index 0646a8ba0ba..8018783b0a0 100644 --- a/doc/src/sgml/pltcl.sgml +++ b/doc/src/sgml/pltcl.sgml @@ -97,7 +97,8 @@ $$ LANGUAGE pltcl; Tcl script as variables named <literal>1</literal> ... <literal><replaceable>n</replaceable></literal>. The result is returned from the Tcl code in the usual way, with - a <literal>return</literal> statement. + a <literal>return</literal> statement. In a procedure, the return value + from the Tcl code is ignored. </para> <para> diff --git a/doc/src/sgml/ref/allfiles.sgml b/doc/src/sgml/ref/allfiles.sgml index 01acc2ef9da..22e68932115 100644 --- a/doc/src/sgml/ref/allfiles.sgml +++ b/doc/src/sgml/ref/allfiles.sgml @@ -26,8 +26,10 @@ Complete list of usable sgml source files in this directory. <!ENTITY alterOperatorClass SYSTEM "alter_opclass.sgml"> <!ENTITY alterOperatorFamily SYSTEM "alter_opfamily.sgml"> <!ENTITY alterPolicy SYSTEM "alter_policy.sgml"> +<!ENTITY alterProcedure SYSTEM "alter_procedure.sgml"> <!ENTITY alterPublication SYSTEM "alter_publication.sgml"> <!ENTITY alterRole SYSTEM "alter_role.sgml"> +<!ENTITY alterRoutine SYSTEM "alter_routine.sgml"> <!ENTITY alterRule SYSTEM "alter_rule.sgml"> <!ENTITY alterSchema SYSTEM "alter_schema.sgml"> <!ENTITY alterServer SYSTEM "alter_server.sgml"> @@ -48,6 +50,7 @@ Complete list of usable sgml source files in this directory. <!ENTITY alterView SYSTEM "alter_view.sgml"> <!ENTITY analyze SYSTEM "analyze.sgml"> <!ENTITY begin SYSTEM "begin.sgml"> +<!ENTITY call SYSTEM "call.sgml"> <!ENTITY checkpoint SYSTEM "checkpoint.sgml"> <!ENTITY close SYSTEM "close.sgml"> <!ENTITY cluster SYSTEM "cluster.sgml"> @@ -75,6 +78,7 @@ Complete list of usable sgml source files in this directory. <!ENTITY createOperatorClass SYSTEM "create_opclass.sgml"> <!ENTITY createOperatorFamily SYSTEM "create_opfamily.sgml"> <!ENTITY createPolicy SYSTEM "create_policy.sgml"> +<!ENTITY createProcedure SYSTEM "create_procedure.sgml"> <!ENTITY createPublication SYSTEM "create_publication.sgml"> <!ENTITY createRole SYSTEM "create_role.sgml"> <!ENTITY createRule SYSTEM "create_rule.sgml"> @@ -122,8 +126,10 @@ Complete list of usable sgml source files in this directory. <!ENTITY dropOperatorFamily SYSTEM "drop_opfamily.sgml"> <!ENTITY dropOwned SYSTEM "drop_owned.sgml"> <!ENTITY dropPolicy SYSTEM "drop_policy.sgml"> +<!ENTITY dropProcedure SYSTEM "drop_procedure.sgml"> <!ENTITY dropPublication SYSTEM "drop_publication.sgml"> <!ENTITY dropRole SYSTEM "drop_role.sgml"> +<!ENTITY dropRoutine SYSTEM "drop_routine.sgml"> <!ENTITY dropRule SYSTEM "drop_rule.sgml"> <!ENTITY dropSchema SYSTEM "drop_schema.sgml"> <!ENTITY dropSequence SYSTEM "drop_sequence.sgml"> diff --git a/doc/src/sgml/ref/alter_default_privileges.sgml b/doc/src/sgml/ref/alter_default_privileges.sgml index ab2c35b4dd0..0c09f1db5cd 100644 --- a/doc/src/sgml/ref/alter_default_privileges.sgml +++ b/doc/src/sgml/ref/alter_default_privileges.sgml @@ -39,7 +39,7 @@ GRANT { { USAGE | SELECT | UPDATE } TO { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { EXECUTE | ALL [ PRIVILEGES ] } - ON FUNCTIONS + ON { FUNCTIONS | ROUTINES } TO { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { USAGE | ALL [ PRIVILEGES ] } @@ -66,7 +66,7 @@ REVOKE [ GRANT OPTION FOR ] REVOKE [ GRANT OPTION FOR ] { EXECUTE | ALL [ PRIVILEGES ] } - ON FUNCTIONS + ON { FUNCTIONS | ROUTINES } FROM { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] @@ -93,7 +93,13 @@ REVOKE [ GRANT OPTION FOR ] affect privileges assigned to already-existing objects.) Currently, only the privileges for schemas, tables (including views and foreign tables), sequences, functions, and types (including domains) can be - altered. + altered. For this command, functions include aggregates and procedures. + The words <literal>FUNCTIONS</literal> and <literal>ROUTINES</literal> are + equivalent in this command. (<literal>ROUTINES</literal> is preferred + going forward as the standard term for functions and procedures taken + together. In earlier PostgreSQL releases, only the + word <literal>FUNCTIONS</literal> was allowed. It is not possible to set + default privileges for functions and procedures separately.) </para> <para> diff --git a/doc/src/sgml/ref/alter_extension.sgml b/doc/src/sgml/ref/alter_extension.sgml index e54925507e1..a2d405d6cdf 100644 --- a/doc/src/sgml/ref/alter_extension.sgml +++ b/doc/src/sgml/ref/alter_extension.sgml @@ -45,6 +45,8 @@ ALTER EXTENSION <replaceable class="parameter">name</replaceable> DROP <replacea OPERATOR CLASS <replaceable class="parameter">object_name</replaceable> USING <replaceable class="parameter">index_method</replaceable> | OPERATOR FAMILY <replaceable class="parameter">object_name</replaceable> USING <replaceable class="parameter">index_method</replaceable> | [ PROCEDURAL ] LANGUAGE <replaceable class="parameter">object_name</replaceable> | + PROCEDURE <replaceable class="parameter">procedure_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] | + ROUTINE <replaceable class="parameter">routine_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] | SCHEMA <replaceable class="parameter">object_name</replaceable> | SEQUENCE <replaceable class="parameter">object_name</replaceable> | SERVER <replaceable class="parameter">object_name</replaceable> | @@ -170,12 +172,14 @@ ALTER EXTENSION <replaceable class="parameter">name</replaceable> DROP <replacea <term><replaceable class="parameter">aggregate_name</replaceable></term> <term><replaceable class="parameter">function_name</replaceable></term> <term><replaceable class="parameter">operator_name</replaceable></term> + <term><replaceable class="parameter">procedure_name</replaceable></term> + <term><replaceable class="parameter">routine_name</replaceable></term> <listitem> <para> The name of an object to be added to or removed from the extension. Names of tables, aggregates, domains, foreign tables, functions, operators, - operator classes, operator families, sequences, text search objects, + operator classes, operator families, procedures, routines, sequences, text search objects, types, and views can be schema-qualified. </para> </listitem> @@ -204,7 +208,7 @@ ALTER EXTENSION <replaceable class="parameter">name</replaceable> DROP <replacea <listitem> <para> - The mode of a function or aggregate + The mode of a function, procedure, or aggregate argument: <literal>IN</literal>, <literal>OUT</literal>, <literal>INOUT</literal>, or <literal>VARIADIC</literal>. If omitted, the default is <literal>IN</literal>. @@ -222,7 +226,7 @@ ALTER EXTENSION <replaceable class="parameter">name</replaceable> DROP <replacea <listitem> <para> - The name of a function or aggregate argument. + The name of a function, procedure, or aggregate argument. Note that <command>ALTER EXTENSION</command> does not actually pay any attention to argument names, since only the argument data types are needed to determine the function's identity. @@ -235,7 +239,7 @@ ALTER EXTENSION <replaceable class="parameter">name</replaceable> DROP <replacea <listitem> <para> - The data type of a function or aggregate argument. + The data type of a function, procedure, or aggregate argument. </para> </listitem> </varlistentry> diff --git a/doc/src/sgml/ref/alter_function.sgml b/doc/src/sgml/ref/alter_function.sgml index 196d2dde0c0..d8747e07482 100644 --- a/doc/src/sgml/ref/alter_function.sgml +++ b/doc/src/sgml/ref/alter_function.sgml @@ -359,6 +359,8 @@ ALTER FUNCTION check_password(text) RESET search_path; <simplelist type="inline"> <member><xref linkend="sql-createfunction"/></member> <member><xref linkend="sql-dropfunction"/></member> + <member><xref linkend="sql-alterprocedure"/></member> + <member><xref linkend="sql-alterroutine"/></member> </simplelist> </refsect1> </refentry> diff --git a/doc/src/sgml/ref/alter_procedure.sgml b/doc/src/sgml/ref/alter_procedure.sgml new file mode 100644 index 00000000000..dae80076d95 --- /dev/null +++ b/doc/src/sgml/ref/alter_procedure.sgml @@ -0,0 +1,281 @@ +<!-- +doc/src/sgml/ref/alter_procedure.sgml +PostgreSQL documentation +--> + +<refentry id="sql-alterprocedure"> + <indexterm zone="sql-alterprocedure"> + <primary>ALTER PROCEDURE</primary> + </indexterm> + + <refmeta> + <refentrytitle>ALTER PROCEDURE</refentrytitle> + <manvolnum>7</manvolnum> + <refmiscinfo>SQL - Language Statements</refmiscinfo> + </refmeta> + + <refnamediv> + <refname>ALTER PROCEDURE</refname> + <refpurpose>change the definition of a procedure</refpurpose> + </refnamediv> + + <refsynopsisdiv> +<synopsis> +ALTER PROCEDURE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] + <replaceable class="parameter">action</replaceable> [ ... ] [ RESTRICT ] +ALTER PROCEDURE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] + RENAME TO <replaceable>new_name</replaceable> +ALTER PROCEDURE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] + OWNER TO { <replaceable>new_owner</replaceable> | CURRENT_USER | SESSION_USER } +ALTER PROCEDURE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] + SET SCHEMA <replaceable>new_schema</replaceable> +ALTER PROCEDURE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] + DEPENDS ON EXTENSION <replaceable>extension_name</replaceable> + +<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase> + + [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER + SET <replaceable class="parameter">configuration_parameter</replaceable> { TO | = } { <replaceable class="parameter">value</replaceable> | DEFAULT } + SET <replaceable class="parameter">configuration_parameter</replaceable> FROM CURRENT + RESET <replaceable class="parameter">configuration_parameter</replaceable> + RESET ALL +</synopsis> + </refsynopsisdiv> + + <refsect1> + <title>Description</title> + + <para> + <command>ALTER PROCEDURE</command> changes the definition of a + procedure. + </para> + + <para> + You must own the procedure to use <command>ALTER PROCEDURE</command>. + To change a procedure's schema, you must also have <literal>CREATE</literal> + privilege on the new schema. + To alter the owner, you must also be a direct or indirect member of the new + owning role, and that role must have <literal>CREATE</literal> privilege on + the procedure's schema. (These restrictions enforce that altering the owner + doesn't do anything you couldn't do by dropping and recreating the procedure. + However, a superuser can alter ownership of any procedure anyway.) + </para> + </refsect1> + + <refsect1> + <title>Parameters</title> + + <variablelist> + <varlistentry> + <term><replaceable class="parameter">name</replaceable></term> + <listitem> + <para> + The name (optionally schema-qualified) of an existing procedure. If no + argument list is specified, the name must be unique in its schema. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">argmode</replaceable></term> + + <listitem> + <para> + The mode of an argument: <literal>IN</literal> or <literal>VARIADIC</literal>. + If omitted, the default is <literal>IN</literal>. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">argname</replaceable></term> + + <listitem> + <para> + The name of an argument. + Note that <command>ALTER PROCEDURE</command> does not actually pay + any attention to argument names, since only the argument data + types are needed to determine the procedure's identity. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">argtype</replaceable></term> + + <listitem> + <para> + The data type(s) of the procedure's arguments (optionally + schema-qualified), if any. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">new_name</replaceable></term> + <listitem> + <para> + The new name of the procedure. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">new_owner</replaceable></term> + <listitem> + <para> + The new owner of the procedure. Note that if the procedure is + marked <literal>SECURITY DEFINER</literal>, it will subsequently + execute as the new owner. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">new_schema</replaceable></term> + <listitem> + <para> + The new schema for the procedure. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">extension_name</replaceable></term> + <listitem> + <para> + The name of the extension that the procedure is to depend on. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><literal><optional> EXTERNAL </optional> SECURITY INVOKER</literal></term> + <term><literal><optional> EXTERNAL </optional> SECURITY DEFINER</literal></term> + + <listitem> + <para> + Change whether the procedure is a security definer or not. The + key word <literal>EXTERNAL</literal> is ignored for SQL + conformance. See <xref linkend="sql-createprocedure"/> for more information about + this capability. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable>configuration_parameter</replaceable></term> + <term><replaceable>value</replaceable></term> + <listitem> + <para> + Add or change the assignment to be made to a configuration parameter + when the procedure is called. If + <replaceable>value</replaceable> is <literal>DEFAULT</literal> + or, equivalently, <literal>RESET</literal> is used, the procedure-local + setting is removed, so that the procedure executes with the value + present in its environment. Use <literal>RESET + ALL</literal> to clear all procedure-local settings. + <literal>SET FROM CURRENT</literal> saves the value of the parameter that + is current when <command>ALTER PROCEDURE</command> is executed as the value + to be applied when the procedure is entered. + </para> + + <para> + See <xref linkend="sql-set"/> and + <xref linkend="runtime-config"/> + for more information about allowed parameter names and values. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><literal>RESTRICT</literal></term> + + <listitem> + <para> + Ignored for conformance with the SQL standard. + </para> + </listitem> + </varlistentry> + </variablelist> + </refsect1> + + <refsect1> + <title>Examples</title> + + <para> + To rename the procedure <literal>insert_data</literal> with two arguments + of type <type>integer</type> to <literal>insert_record</literal>: +<programlisting> +ALTER PROCEDURE insert_data(integer, integer) RENAME TO insert_record; +</programlisting> + </para> + + <para> + To change the owner of the procedure <literal>insert_data</literal> with + two arguments of type <type>integer</type> to <literal>joe</literal>: +<programlisting> +ALTER PROCEDURE insert_data(integer, integer) OWNER TO joe; +</programlisting> + </para> + + <para> + To change the schema of the procedure <literal>insert_data</literal> with + two arguments of type <type>integer</type> + to <literal>accounting</literal>: +<programlisting> +ALTER PROCEDURE insert_data(integer, integer) SET SCHEMA accounting; +</programlisting> + </para> + + <para> + To mark the procedure <literal>insert_data(integer, integer)</literal> as + being dependent on the extension <literal>myext</literal>: +<programlisting> +ALTER PROCEDURE insert_data(integer, integer) DEPENDS ON EXTENSION myext; +</programlisting> + </para> + + <para> + To adjust the search path that is automatically set for a procedure: +<programlisting> +ALTER PROCEDURE check_password(text) SET search_path = admin, pg_temp; +</programlisting> + </para> + + <para> + To disable automatic setting of <varname>search_path</varname> for a procedure: +<programlisting> +ALTER PROCEDURE check_password(text) RESET search_path; +</programlisting> + The procedure will now execute with whatever search path is used by its + caller. + </para> + </refsect1> + + <refsect1> + <title>Compatibility</title> + + <para> + This statement is partially compatible with the <command>ALTER + PROCEDURE</command> statement in the SQL standard. The standard allows more + properties of a procedure to be modified, but does not provide the + ability to rename a procedure, make a procedure a security definer, + attach configuration parameter values to a procedure, + or change the owner, schema, or volatility of a procedure. The standard also + requires the <literal>RESTRICT</literal> key word, which is optional in + <productname>PostgreSQL</productname>. + </para> + </refsect1> + + <refsect1> + <title>See Also</title> + + <simplelist type="inline"> + <member><xref linkend="sql-createprocedure"/></member> + <member><xref linkend="sql-dropprocedure"/></member> + <member><xref linkend="sql-alterfunction"/></member> + <member><xref linkend="sql-alterroutine"/></member> + </simplelist> + </refsect1> +</refentry> diff --git a/doc/src/sgml/ref/alter_routine.sgml b/doc/src/sgml/ref/alter_routine.sgml new file mode 100644 index 00000000000..d1699691e10 --- /dev/null +++ b/doc/src/sgml/ref/alter_routine.sgml @@ -0,0 +1,102 @@ +<!-- +doc/src/sgml/ref/alter_routine.sgml +PostgreSQL documentation +--> + +<refentry id="sql-alterroutine"> + <indexterm zone="sql-alterroutine"> + <primary>ALTER ROUTINE</primary> + </indexterm> + + <refmeta> + <refentrytitle>ALTER ROUTINE</refentrytitle> + <manvolnum>7</manvolnum> + <refmiscinfo>SQL - Language Statements</refmiscinfo> + </refmeta> + + <refnamediv> + <refname>ALTER ROUTINE</refname> + <refpurpose>change the definition of a routine</refpurpose> + </refnamediv> + + <refsynopsisdiv> +<synopsis> +ALTER ROUTINE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] + <replaceable class="parameter">action</replaceable> [ ... ] [ RESTRICT ] +ALTER ROUTINE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] + RENAME TO <replaceable>new_name</replaceable> +ALTER ROUTINE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] + OWNER TO { <replaceable>new_owner</replaceable> | CURRENT_USER | SESSION_USER } +ALTER ROUTINE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] + SET SCHEMA <replaceable>new_schema</replaceable> +ALTER ROUTINE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] + DEPENDS ON EXTENSION <replaceable>extension_name</replaceable> + +<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase> + + IMMUTABLE | STABLE | VOLATILE | [ NOT ] LEAKPROOF + [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER + PARALLEL { UNSAFE | RESTRICTED | SAFE } + COST <replaceable class="parameter">execution_cost</replaceable> + ROWS <replaceable class="parameter">result_rows</replaceable> + SET <replaceable class="parameter">configuration_parameter</replaceable> { TO | = } { <replaceable class="parameter">value</replaceable> | DEFAULT } + SET <replaceable class="parameter">configuration_parameter</replaceable> FROM CURRENT + RESET <replaceable class="parameter">configuration_parameter</replaceable> + RESET ALL +</synopsis> + </refsynopsisdiv> + + <refsect1> + <title>Description</title> + + <para> + <command>ALTER ROUTINE</command> changes the definition of a routine, which + can be an aggregate function, a normal function, or a procedure. See + under <xref linkend="sql-alteraggregate"/>, <xref linkend="sql-alterfunction"/>, + and <xref linkend="sql-alterprocedure"/> for the description of the + parameters, more examples, and further details. + </para> + </refsect1> + + <refsect1> + <title>Examples</title> + + <para> + To rename the routine <literal>foo</literal> for type + <type>integer</type> to <literal>foobar</literal>: +<programlisting> +ALTER ROUTINE foo(integer) RENAME TO foobar; +</programlisting> + This command will work independent of whether <literal>foo</literal> is an + aggregate, function, or procedure. + </para> + </refsect1> + + <refsect1> + <title>Compatibility</title> + + <para> + This statement is partially compatible with the <command>ALTER + ROUTINE</command> statement in the SQL standard. See + under <xref linkend="sql-alterfunction"/> + and <xref linkend="sql-alterprocedure"/> for more details. Allowing + routine names to refer to aggregate functions is + a <productname>PostgreSQL</productname> extension. + </para> + </refsect1> + + <refsect1> + <title>See Also</title> + + <simplelist type="inline"> + <member><xref linkend="sql-alteraggregate"/></member> + <member><xref linkend="sql-alterfunction"/></member> + <member><xref linkend="sql-alterprocedure"/></member> + <member><xref linkend="sql-droproutine"/></member> + </simplelist> + + <para> + Note that there is no <literal>CREATE ROUTINE</literal> command. + </para> + </refsect1> +</refentry> diff --git a/doc/src/sgml/ref/call.sgml b/doc/src/sgml/ref/call.sgml new file mode 100644 index 00000000000..2741d8d15ec --- /dev/null +++ b/doc/src/sgml/ref/call.sgml @@ -0,0 +1,97 @@ +<!-- +doc/src/sgml/ref/call.sgml +PostgreSQL documentation +--> + +<refentry id="sql-call"> + <indexterm zone="sql-call"> + <primary>CALL</primary> + </indexterm> + + <refmeta> + <refentrytitle>CALL</refentrytitle> + <manvolnum>7</manvolnum> + <refmiscinfo>SQL - Language Statements</refmiscinfo> + </refmeta> + + <refnamediv> + <refname>CALL</refname> + <refpurpose>invoke a procedure</refpurpose> + </refnamediv> + + <refsynopsisdiv> +<synopsis> +CALL <replaceable class="parameter">name</replaceable> ( [ <replaceable class="parameter">argument</replaceable> ] [ , ...] ) +</synopsis> + </refsynopsisdiv> + + <refsect1> + <title>Description</title> + + <para> + <command>CALL</command> executes a procedure. + </para> + </refsect1> + + <refsect1> + <title>Parameters</title> + + <variablelist> + <varlistentry> + <term><replaceable class="parameter">name</replaceable></term> + <listitem> + <para> + The name (optionally schema-qualified) of the procedure. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">argument</replaceable></term> + <listitem> + <para> + An argument for the procedure call. + See <xref linkend="sql-syntax-calling-funcs"/> for the full details on + function and procedure call syntax, including use of named parameters. + </para> + </listitem> + </varlistentry> + </variablelist> + </refsect1> + + <refsect1> + <title>Notes</title> + + <para> + The user must have <literal>EXECUTE</literal> privilege on the procedure in + order to be allowed to invoke it. + </para> + + <para> + To call a function (not a procedure), use <command>SELECT</command> instead. + </para> + </refsect1> + + <refsect1> + <title>Examples</title> +<programlisting> +CALL do_db_maintenance(); +</programlisting> + </refsect1> + + <refsect1> + <title>Compatibility</title> + + <para> + <command>CALL</command> conforms to the SQL standard. + </para> + </refsect1> + + <refsect1> + <title>See Also</title> + + <simplelist type="inline"> + <member><xref linkend="sql-createprocedure"/></member> + </simplelist> + </refsect1> +</refentry> diff --git a/doc/src/sgml/ref/comment.sgml b/doc/src/sgml/ref/comment.sgml index 7d66c1a34ca..965c5a40ad7 100644 --- a/doc/src/sgml/ref/comment.sgml +++ b/doc/src/sgml/ref/comment.sgml @@ -46,8 +46,10 @@ COMMENT ON OPERATOR FAMILY <replaceable class="parameter">object_name</replaceable> USING <replaceable class="parameter">index_method</replaceable> | POLICY <replaceable class="parameter">policy_name</replaceable> ON <replaceable class="parameter">table_name</replaceable> | [ PROCEDURAL ] LANGUAGE <replaceable class="parameter">object_name</replaceable> | + PROCEDURE <replaceable class="parameter">procedure_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] | PUBLICATION <replaceable class="parameter">object_name</replaceable> | ROLE <replaceable class="parameter">object_name</replaceable> | + ROUTINE <replaceable class="parameter">routine_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] | RULE <replaceable class="parameter">rule_name</replaceable> ON <replaceable class="parameter">table_name</replaceable> | SCHEMA <replaceable class="parameter">object_name</replaceable> | SEQUENCE <replaceable class="parameter">object_name</replaceable> | @@ -121,13 +123,15 @@ COMMENT ON <term><replaceable class="parameter">function_name</replaceable></term> <term><replaceable class="parameter">operator_name</replaceable></term> <term><replaceable class="parameter">policy_name</replaceable></term> + <term><replaceable class="parameter">procedure_name</replaceable></term> + <term><replaceable class="parameter">routine_name</replaceable></term> <term><replaceable class="parameter">rule_name</replaceable></term> <term><replaceable class="parameter">trigger_name</replaceable></term> <listitem> <para> The name of the object to be commented. Names of tables, aggregates, collations, conversions, domains, foreign tables, functions, - indexes, operators, operator classes, operator families, sequences, + indexes, operators, operator classes, operator families, procedures, routines, sequences, statistics, text search objects, types, and views can be schema-qualified. When commenting on a column, <replaceable class="parameter">relation_name</replaceable> must refer @@ -170,7 +174,7 @@ COMMENT ON <term><replaceable class="parameter">argmode</replaceable></term> <listitem> <para> - The mode of a function or aggregate + The mode of a function, procedure, or aggregate argument: <literal>IN</literal>, <literal>OUT</literal>, <literal>INOUT</literal>, or <literal>VARIADIC</literal>. If omitted, the default is <literal>IN</literal>. @@ -187,7 +191,7 @@ COMMENT ON <term><replaceable class="parameter">argname</replaceable></term> <listitem> <para> - The name of a function or aggregate argument. + The name of a function, procedure, or aggregate argument. Note that <command>COMMENT</command> does not actually pay any attention to argument names, since only the argument data types are needed to determine the function's identity. @@ -199,7 +203,7 @@ COMMENT ON <term><replaceable class="parameter">argtype</replaceable></term> <listitem> <para> - The data type of a function or aggregate argument. + The data type of a function, procedure, or aggregate argument. </para> </listitem> </varlistentry> @@ -325,6 +329,7 @@ COMMENT ON OPERATOR - (NONE, integer) IS 'Unary minus'; COMMENT ON OPERATOR CLASS int4ops USING btree IS '4 byte integer operators for btrees'; COMMENT ON OPERATOR FAMILY integer_ops USING btree IS 'all integer operators for btrees'; COMMENT ON POLICY my_policy ON mytable IS 'Filter rows by users'; +COMMENT ON PROCEDURE my_proc (integer, integer) IS 'Runs a report'; COMMENT ON ROLE my_role IS 'Administration group for finance tables'; COMMENT ON RULE my_rule ON my_table IS 'Logs updates of employee records'; COMMENT ON SCHEMA my_schema IS 'Departmental data'; diff --git a/doc/src/sgml/ref/create_function.sgml b/doc/src/sgml/ref/create_function.sgml index 75331165fef..fd229d11937 100644 --- a/doc/src/sgml/ref/create_function.sgml +++ b/doc/src/sgml/ref/create_function.sgml @@ -55,9 +55,9 @@ CREATE [ OR REPLACE ] FUNCTION <para> If a schema name is included, then the function is created in the specified schema. Otherwise it is created in the current schema. - The name of the new function must not match any existing function + The name of the new function must not match any existing function or procedure with the same input argument types in the same schema. However, - functions of different argument types can share a name (this is + functions and procedures of different argument types can share a name (this is called <firstterm>overloading</firstterm>). </para> @@ -450,7 +450,7 @@ CREATE [ OR REPLACE ] FUNCTION </varlistentry> <varlistentry> - <term><replaceable class="parameter">execution_cost</replaceable></term> + <term><literal>COST</literal> <replaceable class="parameter">execution_cost</replaceable></term> <listitem> <para> @@ -466,7 +466,7 @@ CREATE [ OR REPLACE ] FUNCTION </varlistentry> <varlistentry> - <term><replaceable class="parameter">result_rows</replaceable></term> + <term><literal>ROWS</literal> <replaceable class="parameter">result_rows</replaceable></term> <listitem> <para> @@ -818,7 +818,7 @@ COMMIT; <title>Compatibility</title> <para> - A <command>CREATE FUNCTION</command> command is defined in SQL:1999 and later. + A <command>CREATE FUNCTION</command> command is defined in the SQL standard. The <productname>PostgreSQL</productname> version is similar but not fully compatible. The attributes are not portable, neither are the different available languages. diff --git a/doc/src/sgml/ref/create_procedure.sgml b/doc/src/sgml/ref/create_procedure.sgml new file mode 100644 index 00000000000..d712043824a --- /dev/null +++ b/doc/src/sgml/ref/create_procedure.sgml @@ -0,0 +1,341 @@ +<!-- +doc/src/sgml/ref/create_procedure.sgml +--> + +<refentry id="sql-createprocedure"> + <indexterm zone="sql-createprocedure"> + <primary>CREATE PROCEDURE</primary> + </indexterm> + + <refmeta> + <refentrytitle>CREATE PROCEDURE</refentrytitle> + <manvolnum>7</manvolnum> + <refmiscinfo>SQL - Language Statements</refmiscinfo> + </refmeta> + + <refnamediv> + <refname>CREATE PROCEDURE</refname> + <refpurpose>define a new procedure</refpurpose> + </refnamediv> + + <refsynopsisdiv> +<synopsis> +CREATE [ OR REPLACE ] PROCEDURE + <replaceable class="parameter">name</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [ { DEFAULT | = } <replaceable class="parameter">default_expr</replaceable> ] [, ...] ] ) + { LANGUAGE <replaceable class="parameter">lang_name</replaceable> + | TRANSFORM { FOR TYPE <replaceable class="parameter">type_name</replaceable> } [, ... ] + | [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER + | SET <replaceable class="parameter">configuration_parameter</replaceable> { TO <replaceable class="parameter">value</replaceable> | = <replaceable class="parameter">value</replaceable> | FROM CURRENT } + | AS '<replaceable class="parameter">definition</replaceable>' + | AS '<replaceable class="parameter">obj_file</replaceable>', '<replaceable class="parameter">link_symbol</replaceable>' + } ... +</synopsis> + </refsynopsisdiv> + + <refsect1 id="sql-createprocedure-description"> + <title>Description</title> + + <para> + <command>CREATE PROCEDURE</command> defines a new procedure. + <command>CREATE OR REPLACE PROCEDURE</command> will either create a + new procedure, or replace an existing definition. + To be able to define a procedure, the user must have the + <literal>USAGE</literal> privilege on the language. + </para> + + <para> + If a schema name is included, then the procedure is created in the + specified schema. Otherwise it is created in the current schema. + The name of the new procedure must not match any existing procedure or function + with the same input argument types in the same schema. However, + procedures and functions of different argument types can share a name (this is + called <firstterm>overloading</firstterm>). + </para> + + <para> + To replace the current definition of an existing procedure, use + <command>CREATE OR REPLACE PROCEDURE</command>. It is not possible + to change the name or argument types of a procedure this way (if you + tried, you would actually be creating a new, distinct procedure). + </para> + + <para> + When <command>CREATE OR REPLACE PROCEDURE</command> is used to replace an + existing procedure, the ownership and permissions of the procedure + do not change. All other procedure properties are assigned the + values specified or implied in the command. You must own the procedure + to replace it (this includes being a member of the owning role). + </para> + + <para> + The user that creates the procedure becomes the owner of the procedure. + </para> + + <para> + To be able to create a procedure, you must have <literal>USAGE</literal> + privilege on the argument types. + </para> + </refsect1> + + <refsect1> + <title>Parameters</title> + + <variablelist> + <varlistentry> + <term><replaceable class="parameter">name</replaceable></term> + + <listitem> + <para> + The name (optionally schema-qualified) of the procedure to create. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">argmode</replaceable></term> + + <listitem> + <para> + The mode of an argument: <literal>IN</literal> or <literal>VARIADIC</literal>. + If omitted, the default is <literal>IN</literal>. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">argname</replaceable></term> + + <listitem> + <para> + The name of an argument. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">argtype</replaceable></term> + + <listitem> + <para> + The data type(s) of the procedure's arguments (optionally + schema-qualified), if any. The argument types can be base, composite, + or domain types, or can reference the type of a table column. + </para> + <para> + Depending on the implementation language it might also be allowed + to specify <quote>pseudo-types</quote> such as <type>cstring</type>. + Pseudo-types indicate that the actual argument type is either + incompletely specified, or outside the set of ordinary SQL data types. + </para> + <para> + The type of a column is referenced by writing + <literal><replaceable + class="parameter">table_name</replaceable>.<replaceable + class="parameter">column_name</replaceable>%TYPE</literal>. + Using this feature can sometimes help make a procedure independent of + changes to the definition of a table. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">default_expr</replaceable></term> + + <listitem> + <para> + An expression to be used as default value if the parameter is + not specified. The expression has to be coercible to the + argument type of the parameter. + All input parameters following a + parameter with a default value must have default values as well. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">lang_name</replaceable></term> + + <listitem> + <para> + The name of the language that the procedure is implemented in. + It can be <literal>sql</literal>, <literal>c</literal>, + <literal>internal</literal>, or the name of a user-defined + procedural language, e.g. <literal>plpgsql</literal>. Enclosing the + name in single quotes is deprecated and requires matching case. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><literal>TRANSFORM { FOR TYPE <replaceable class="parameter">type_name</replaceable> } [, ... ] }</literal></term> + + <listitem> + <para> + Lists which transforms a call to the procedure should apply. Transforms + convert between SQL types and language-specific data types; + see <xref linkend="sql-createtransform"/>. Procedural language + implementations usually have hardcoded knowledge of the built-in types, + so those don't need to be listed here. If a procedural language + implementation does not know how to handle a type and no transform is + supplied, it will fall back to a default behavior for converting data + types, but this depends on the implementation. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><literal><optional>EXTERNAL</optional> SECURITY INVOKER</literal></term> + <term><literal><optional>EXTERNAL</optional> SECURITY DEFINER</literal></term> + + <listitem> + <para><literal>SECURITY INVOKER</literal> indicates that the procedure + is to be executed with the privileges of the user that calls it. + That is the default. <literal>SECURITY DEFINER</literal> + specifies that the procedure is to be executed with the + privileges of the user that owns it. + </para> + + <para> + The key word <literal>EXTERNAL</literal> is allowed for SQL + conformance, but it is optional since, unlike in SQL, this feature + applies to all procedures not only external ones. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable>configuration_parameter</replaceable></term> + <term><replaceable>value</replaceable></term> + <listitem> + <para> + The <literal>SET</literal> clause causes the specified configuration + parameter to be set to the specified value when the procedure is + entered, and then restored to its prior value when the procedure exits. + <literal>SET FROM CURRENT</literal> saves the value of the parameter that + is current when <command>CREATE PROCEDURE</command> is executed as the value + to be applied when the procedure is entered. + </para> + + <para> + If a <literal>SET</literal> clause is attached to a procedure, then + the effects of a <command>SET LOCAL</command> command executed inside the + procedure for the same variable are restricted to the procedure: the + configuration parameter's prior value is still restored at procedure exit. + However, an ordinary + <command>SET</command> command (without <literal>LOCAL</literal>) overrides the + <literal>SET</literal> clause, much as it would do for a previous <command>SET + LOCAL</command> command: the effects of such a command will persist after + procedure exit, unless the current transaction is rolled back. + </para> + + <para> + See <xref linkend="sql-set"/> and + <xref linkend="runtime-config"/> + for more information about allowed parameter names and values. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">definition</replaceable></term> + + <listitem> + <para> + A string constant defining the procedure; the meaning depends on the + language. It can be an internal procedure name, the path to an + object file, an SQL command, or text in a procedural language. + </para> + + <para> + It is often helpful to use dollar quoting (see <xref + linkend="sql-syntax-dollar-quoting"/>) to write the procedure definition + string, rather than the normal single quote syntax. Without dollar + quoting, any single quotes or backslashes in the procedure definition must + be escaped by doubling them. + </para> + + </listitem> + </varlistentry> + + <varlistentry> + <term><literal><replaceable class="parameter">obj_file</replaceable>, <replaceable class="parameter">link_symbol</replaceable></literal></term> + + <listitem> + <para> + This form of the <literal>AS</literal> clause is used for + dynamically loadable C language procedures when the procedure name + in the C language source code is not the same as the name of + the SQL procedure. The string <replaceable + class="parameter">obj_file</replaceable> is the name of the shared + library file containing the compiled C procedure, and is interpreted + as for the <xref linkend="sql-load"/> command. The string + <replaceable class="parameter">link_symbol</replaceable> is the + procedure's link symbol, that is, the name of the procedure in the C + language source code. If the link symbol is omitted, it is assumed + to be the same as the name of the SQL procedure being defined. + </para> + + <para> + When repeated <command>CREATE PROCEDURE</command> calls refer to + the same object file, the file is only loaded once per session. + To unload and + reload the file (perhaps during development), start a new session. + </para> + + </listitem> + </varlistentry> + </variablelist> + </refsect1> + + <refsect1 id="sql-createprocedure-notes"> + <title>Notes</title> + + <para> + See <xref linkend="sql-createfunction"/> for more details on function + creation that also apply to procedures. + </para> + + <para> + Use <xref linkend="sql-call"/> to execute a procedure. + </para> + </refsect1> + + <refsect1 id="sql-createprocedure-examples"> + <title>Examples</title> + +<programlisting> +CREATE PROCEDURE insert_data(a integer, b integer) +LANGUAGE SQL +AS $$ +INSERT INTO tbl VALUES (a); +INSERT INTO tbl VALUES (b); +$$; + +CALL insert_data(1, 2); +</programlisting> + </refsect1> + + <refsect1 id="sql-createprocedure-compat"> + <title>Compatibility</title> + + <para> + A <command>CREATE PROCEDURE</command> command is defined in the SQL + standard. The <productname>PostgreSQL</productname> version is similar but + not fully compatible. For details see + also <xref linkend="sql-createfunction"/>. + </para> + </refsect1> + + + <refsect1> + <title>See Also</title> + + <simplelist type="inline"> + <member><xref linkend="sql-alterprocedure"/></member> + <member><xref linkend="sql-dropprocedure"/></member> + <member><xref linkend="sql-call"/></member> + <member><xref linkend="sql-createfunction"/></member> + </simplelist> + </refsect1> + +</refentry> diff --git a/doc/src/sgml/ref/drop_function.sgml b/doc/src/sgml/ref/drop_function.sgml index eda1a59c846..127fdfe4197 100644 --- a/doc/src/sgml/ref/drop_function.sgml +++ b/doc/src/sgml/ref/drop_function.sgml @@ -185,6 +185,8 @@ DROP FUNCTION update_employee_salaries(); <simplelist type="inline"> <member><xref linkend="sql-createfunction"/></member> <member><xref linkend="sql-alterfunction"/></member> + <member><xref linkend="sql-dropprocedure"/></member> + <member><xref linkend="sql-droproutine"/></member> </simplelist> </refsect1> diff --git a/doc/src/sgml/ref/drop_procedure.sgml b/doc/src/sgml/ref/drop_procedure.sgml new file mode 100644 index 00000000000..fef61b66ac1 --- /dev/null +++ b/doc/src/sgml/ref/drop_procedure.sgml @@ -0,0 +1,162 @@ +<!-- +doc/src/sgml/ref/drop_procedure.sgml +PostgreSQL documentation +--> + +<refentry id="sql-dropprocedure"> + <indexterm zone="sql-dropprocedure"> + <primary>DROP PROCEDURE</primary> + </indexterm> + + <refmeta> + <refentrytitle>DROP PROCEDURE</refentrytitle> + <manvolnum>7</manvolnum> + <refmiscinfo>SQL - Language Statements</refmiscinfo> + </refmeta> + + <refnamediv> + <refname>DROP PROCEDURE</refname> + <refpurpose>remove a procedure</refpurpose> + </refnamediv> + + <refsynopsisdiv> +<synopsis> +DROP PROCEDURE [ IF EXISTS ] <replaceable class="parameter">name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] [, ...] + [ CASCADE | RESTRICT ] +</synopsis> + </refsynopsisdiv> + + <refsect1> + <title>Description</title> + + <para> + <command>DROP PROCEDURE</command> removes the definition of an existing + procedure. To execute this command the user must be the + owner of the procedure. The argument types to the + procedure must be specified, since several different procedures + can exist with the same name and different argument lists. + </para> + </refsect1> + + <refsect1> + <title>Parameters</title> + + <variablelist> + <varlistentry> + <term><literal>IF EXISTS</literal></term> + <listitem> + <para> + Do not throw an error if the procedure does not exist. A notice is issued + in this case. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">name</replaceable></term> + <listitem> + <para> + The name (optionally schema-qualified) of an existing procedure. If no + argument list is specified, the name must be unique in its schema. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">argmode</replaceable></term> + + <listitem> + <para> + The mode of an argument: <literal>IN</literal> or <literal>VARIADIC</literal>. + If omitted, the default is <literal>IN</literal>. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">argname</replaceable></term> + + <listitem> + <para> + The name of an argument. + Note that <command>DROP PROCEDURE</command> does not actually pay + any attention to argument names, since only the argument data + types are needed to determine the procedure's identity. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="parameter">argtype</replaceable></term> + + <listitem> + <para> + The data type(s) of the procedure's arguments (optionally + schema-qualified), if any. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><literal>CASCADE</literal></term> + <listitem> + <para> + Automatically drop objects that depend on the procedure, + and in turn all objects that depend on those objects + (see <xref linkend="ddl-depend"/>). + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><literal>RESTRICT</literal></term> + <listitem> + <para> + Refuse to drop the procedure if any objects depend on it. This + is the default. + </para> + </listitem> + </varlistentry> + </variablelist> + </refsect1> + + <refsect1 id="sql-dropprocedure-examples"> + <title>Examples</title> + +<programlisting> +DROP PROCEDURE do_db_maintenance(); +</programlisting> + </refsect1> + + <refsect1 id="sql-dropprocedure-compatibility"> + <title>Compatibility</title> + + <para> + This command conforms to the SQL standard, with + these <productname>PostgreSQL</productname> extensions: + <itemizedlist> + <listitem> + <para>The standard only allows one procedure to be dropped per command.</para> + </listitem> + <listitem> + <para>The <literal>IF EXISTS</literal> option</para> + </listitem> + <listitem> + <para>The ability to specify argument modes and names</para> + </listitem> + </itemizedlist> + </para> + </refsect1> + + <refsect1> + <title>See Also</title> + + <simplelist type="inline"> + <member><xref linkend="sql-createprocedure"/></member> + <member><xref linkend="sql-alterprocedure"/></member> + <member><xref linkend="sql-dropfunction"/></member> + <member><xref linkend="sql-droproutine"/></member> + </simplelist> + </refsect1> + +</refentry> diff --git a/doc/src/sgml/ref/drop_routine.sgml b/doc/src/sgml/ref/drop_routine.sgml new file mode 100644 index 00000000000..5cd1a0f11eb --- /dev/null +++ b/doc/src/sgml/ref/drop_routine.sgml @@ -0,0 +1,94 @@ +<!-- +doc/src/sgml/ref/drop_routine.sgml +PostgreSQL documentation +--> + +<refentry id="sql-droproutine"> + <indexterm zone="sql-droproutine"> + <primary>DROP ROUTINE</primary> + </indexterm> + + <refmeta> + <refentrytitle>DROP ROUTINE</refentrytitle> + <manvolnum>7</manvolnum> + <refmiscinfo>SQL - Language Statements</refmiscinfo> + </refmeta> + + <refnamediv> + <refname>DROP ROUTINE</refname> + <refpurpose>remove a routine</refpurpose> + </refnamediv> + + <refsynopsisdiv> +<synopsis> +DROP ROUTINE [ IF EXISTS ] <replaceable class="parameter">name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] [, ...] + [ CASCADE | RESTRICT ] +</synopsis> + </refsynopsisdiv> + + <refsect1> + <title>Description</title> + + <para> + <command>DROP ROUTINE</command> removes the definition of an existing + routine, which can be an aggregate function, a normal function, or a + procedure. See + under <xref linkend="sql-dropaggregate"/>, <xref linkend="sql-dropfunction"/>, + and <xref linkend="sql-dropprocedure"/> for the description of the + parameters, more examples, and further details. + </para> + </refsect1> + + <refsect1 id="sql-droproutine-examples"> + <title>Examples</title> + + <para> + To drop the routine <literal>foo</literal> for type + <type>integer</type>: +<programlisting> +DROP ROUTINE foo(integer); +</programlisting> + This command will work independent of whether <literal>foo</literal> is an + aggregate, function, or procedure. + </para> + </refsect1> + + <refsect1 id="sql-droproutine-compatibility"> + <title>Compatibility</title> + + <para> + This command conforms to the SQL standard, with + these <productname>PostgreSQL</productname> extensions: + <itemizedlist> + <listitem> + <para>The standard only allows one routine to be dropped per command.</para> + </listitem> + <listitem> + <para>The <literal>IF EXISTS</literal> option</para> + </listitem> + <listitem> + <para>The ability to specify argument modes and names</para> + </listitem> + <listitem> + <para>Aggregate functions are an extension.</para> + </listitem> + </itemizedlist> + </para> + </refsect1> + + <refsect1> + <title>See Also</title> + + <simplelist type="inline"> + <member><xref linkend="sql-dropaggregate"/></member> + <member><xref linkend="sql-dropfunction"/></member> + <member><xref linkend="sql-dropprocedure"/></member> + <member><xref linkend="sql-alterroutine"/></member> + </simplelist> + + <para> + Note that there is no <literal>CREATE ROUTINE</literal> command. + </para> + </refsect1> + +</refentry> diff --git a/doc/src/sgml/ref/grant.sgml b/doc/src/sgml/ref/grant.sgml index a5e895d09d7..ff64c7a3bae 100644 --- a/doc/src/sgml/ref/grant.sgml +++ b/doc/src/sgml/ref/grant.sgml @@ -55,8 +55,8 @@ GRANT { USAGE | ALL [ PRIVILEGES ] } TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ] GRANT { EXECUTE | ALL [ PRIVILEGES ] } - ON { FUNCTION <replaceable>function_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">arg_name</replaceable> ] <replaceable class="parameter">arg_type</replaceable> [, ...] ] ) ] [, ...] - | ALL FUNCTIONS IN SCHEMA <replaceable class="parameter">schema_name</replaceable> [, ...] } + ON { { FUNCTION | PROCEDURE | ROUTINE } <replaceable>routine_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">arg_name</replaceable> ] <replaceable class="parameter">arg_type</replaceable> [, ...] ] ) ] [, ...] + | ALL { FUNCTIONS | PROCEDURES | ROUTINES } IN SCHEMA <replaceable class="parameter">schema_name</replaceable> [, ...] } TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ] GRANT { USAGE | ALL [ PRIVILEGES ] } @@ -96,7 +96,7 @@ GRANT <replaceable class="parameter">role_name</replaceable> [, ...] TO <replace <para> The <command>GRANT</command> command has two basic variants: one that grants privileges on a database object (table, column, view, foreign - table, sequence, database, foreign-data wrapper, foreign server, function, + table, sequence, database, foreign-data wrapper, foreign server, function, procedure, procedural language, schema, or tablespace), and one that grants membership in a role. These variants are similar in many ways, but they are different enough to be described separately. @@ -115,8 +115,11 @@ GRANT <replaceable class="parameter">role_name</replaceable> [, ...] TO <replace <para> There is also an option to grant privileges on all objects of the same type within one or more schemas. This functionality is currently supported - only for tables, sequences, and functions (but note that <literal>ALL - TABLES</literal> is considered to include views and foreign tables). + only for tables, sequences, functions, and procedures. <literal>ALL + TABLES</literal> also affects views and foreign tables, just like the + specific-object <command>GRANT</command> command. <literal>ALL + FUNCTIONS</literal> also affects aggregate functions, but not procedures, + again just like the specific-object <command>GRANT</command> command. </para> <para> @@ -169,7 +172,7 @@ GRANT <replaceable class="parameter">role_name</replaceable> [, ...] TO <replace granted to <literal>PUBLIC</literal> are as follows: <literal>CONNECT</literal> and <literal>TEMPORARY</literal> (create temporary tables) privileges for databases; - <literal>EXECUTE</literal> privilege for functions; and + <literal>EXECUTE</literal> privilege for functions and procedures; and <literal>USAGE</literal> privilege for languages and data types (including domains). The object owner can, of course, <command>REVOKE</command> @@ -329,10 +332,12 @@ GRANT <replaceable class="parameter">role_name</replaceable> [, ...] TO <replace <term><literal>EXECUTE</literal></term> <listitem> <para> - Allows the use of the specified function and the use of any - operators that are implemented on top of the function. This is - the only type of privilege that is applicable to functions. - (This syntax works for aggregate functions, as well.) + Allows the use of the specified function or procedure and the use of + any operators that are implemented on top of the function. This is the + only type of privilege that is applicable to functions and procedures. + The <literal>FUNCTION</literal> syntax also works for aggregate + functions. Alternatively, use <literal>ROUTINE</literal> to refer to a function, + aggregate function, or procedure regardless of what it is. </para> </listitem> </varlistentry> diff --git a/doc/src/sgml/ref/revoke.sgml b/doc/src/sgml/ref/revoke.sgml index 4d133a782b6..7018202f144 100644 --- a/doc/src/sgml/ref/revoke.sgml +++ b/doc/src/sgml/ref/revoke.sgml @@ -70,8 +70,8 @@ REVOKE [ GRANT OPTION FOR ] REVOKE [ GRANT OPTION FOR ] { EXECUTE | ALL [ PRIVILEGES ] } - ON { FUNCTION <replaceable>function_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">arg_name</replaceable> ] <replaceable class="parameter">arg_type</replaceable> [, ...] ] ) ] [, ...] - | ALL FUNCTIONS IN SCHEMA <replaceable>schema_name</replaceable> [, ...] } + ON { { FUNCTION | PROCEDURE | ROUTINE } <replaceable>function_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">arg_name</replaceable> ] <replaceable class="parameter">arg_type</replaceable> [, ...] ] ) ] [, ...] + | ALL { FUNCTIONS | PROCEDURES | ROUTINES } IN SCHEMA <replaceable>schema_name</replaceable> [, ...] } FROM { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] diff --git a/doc/src/sgml/ref/security_label.sgml b/doc/src/sgml/ref/security_label.sgml index d52113e0359..e9cfdec9f94 100644 --- a/doc/src/sgml/ref/security_label.sgml +++ b/doc/src/sgml/ref/security_label.sgml @@ -34,8 +34,10 @@ SECURITY LABEL [ FOR <replaceable class="parameter">provider</replaceable> ] ON LARGE OBJECT <replaceable class="parameter">large_object_oid</replaceable> | MATERIALIZED VIEW <replaceable class="parameter">object_name</replaceable> | [ PROCEDURAL ] LANGUAGE <replaceable class="parameter">object_name</replaceable> | + PROCEDURE <replaceable class="parameter">procedure_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] | PUBLICATION <replaceable class="parameter">object_name</replaceable> | ROLE <replaceable class="parameter">object_name</replaceable> | + ROUTINE <replaceable class="parameter">routine_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] | SCHEMA <replaceable class="parameter">object_name</replaceable> | SEQUENCE <replaceable class="parameter">object_name</replaceable> | SUBSCRIPTION <replaceable class="parameter">object_name</replaceable> | @@ -93,10 +95,12 @@ SECURITY LABEL [ FOR <replaceable class="parameter">provider</replaceable> ] ON <term><replaceable class="parameter">table_name.column_name</replaceable></term> <term><replaceable class="parameter">aggregate_name</replaceable></term> <term><replaceable class="parameter">function_name</replaceable></term> + <term><replaceable class="parameter">procedure_name</replaceable></term> + <term><replaceable class="parameter">routine_name</replaceable></term> <listitem> <para> The name of the object to be labeled. Names of tables, - aggregates, domains, foreign tables, functions, sequences, types, and + aggregates, domains, foreign tables, functions, procedures, routines, sequences, types, and views can be schema-qualified. </para> </listitem> @@ -119,7 +123,7 @@ SECURITY LABEL [ FOR <replaceable class="parameter">provider</replaceable> ] ON <listitem> <para> - The mode of a function or aggregate + The mode of a function, procedure, or aggregate argument: <literal>IN</literal>, <literal>OUT</literal>, <literal>INOUT</literal>, or <literal>VARIADIC</literal>. If omitted, the default is <literal>IN</literal>. @@ -137,7 +141,7 @@ SECURITY LABEL [ FOR <replaceable class="parameter">provider</replaceable> ] ON <listitem> <para> - The name of a function or aggregate argument. + The name of a function, procedure, or aggregate argument. Note that <command>SECURITY LABEL</command> does not actually pay any attention to argument names, since only the argument data types are needed to determine the function's identity. @@ -150,7 +154,7 @@ SECURITY LABEL [ FOR <replaceable class="parameter">provider</replaceable> ] ON <listitem> <para> - The data type of a function or aggregate argument. + The data type of a function, procedure, or aggregate argument. </para> </listitem> </varlistentry> diff --git a/doc/src/sgml/reference.sgml b/doc/src/sgml/reference.sgml index d20eaa87e76..d27fb414f7c 100644 --- a/doc/src/sgml/reference.sgml +++ b/doc/src/sgml/reference.sgml @@ -54,8 +54,10 @@ &alterOperatorClass; &alterOperatorFamily; &alterPolicy; + &alterProcedure; &alterPublication; &alterRole; + &alterRoutine; &alterRule; &alterSchema; &alterSequence; @@ -76,6 +78,7 @@ &alterView; &analyze; &begin; + &call; &checkpoint; &close; &cluster; @@ -103,6 +106,7 @@ &createOperatorClass; &createOperatorFamily; &createPolicy; + &createProcedure; &createPublication; &createRole; &createRule; @@ -150,8 +154,10 @@ &dropOperatorFamily; &dropOwned; &dropPolicy; + &dropProcedure; &dropPublication; &dropRole; + &dropRoutine; &dropRule; &dropSchema; &dropSequence; diff --git a/doc/src/sgml/xfunc.sgml b/doc/src/sgml/xfunc.sgml index 508ee7a96c0..bbc3766cc21 100644 --- a/doc/src/sgml/xfunc.sgml +++ b/doc/src/sgml/xfunc.sgml @@ -72,6 +72,39 @@ </para> </sect1> + <sect1 id="xproc"> + <title>User-defined Procedures</title> + + <indexterm zone="xproc"> + <primary>procedure</primary> + <secondary>user-defined</secondary> + </indexterm> + + <para> + A procedure is a database object similar to a function. The difference is + that a procedure does not return a value, so there is no return type + declaration. While a function is called as part of a query or DML + command, a procedure is called explicitly using + the <xref linkend="sql-call"/> statement. + </para> + + <para> + The explanations on how to define user-defined functions in the rest of + this chapter apply to procedures as well, except that + the <xref linkend="sql-createprocedure"/> command is used instead, there is + no return type, and some other features such as strictness don't apply. + </para> + + <para> + Collectively, functions and procedures are also known + as <firstterm>routines</firstterm><indexterm><primary>routine</primary></indexterm>. + There are commands such as <xref linkend="sql-alterroutine"/> + and <xref linkend="sql-droproutine"/> that can operate on functions and + procedures without having to know which kind it is. Note, however, that + there is no <literal>CREATE ROUTINE</literal> command. + </para> + </sect1> + <sect1 id="xfunc-sql"> <title>Query Language (<acronym>SQL</acronym>) Functions</title> |