<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>
<listitem>
<para>
- Functions and operators
+ Functions, procedures, and operators
</para>
</listitem>
<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>
<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>
<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>
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>
<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>
<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>
<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>
<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>
as discussed below.
</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:
<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>
</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>
<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
<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>
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>
<!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">
<!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">
<!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">
<!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">
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 ] }
REVOKE [ GRANT OPTION FOR ]
{ EXECUTE | ALL [ PRIVILEGES ] }
- ON FUNCTIONS
+ ON { FUNCTIONS | ROUTINES }
FROM { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...]
[ CASCADE | RESTRICT ]
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>
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> |
<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>
<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>.
<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.
<listitem>
<para>
- The data type of a function or aggregate argument.
+ The data type of a function, procedure, or aggregate argument.
</para>
</listitem>
</varlistentry>
<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>
--- /dev/null
+<!--
+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>
--- /dev/null
+<!--
+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>
--- /dev/null
+<!--
+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>
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> |
<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
<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>.
<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.
<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>
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';
<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>
</varlistentry>
<varlistentry>
- <term><replaceable class="parameter">execution_cost</replaceable></term>
+ <term><literal>COST</literal> <replaceable class="parameter">execution_cost</replaceable></term>
<listitem>
<para>
</varlistentry>
<varlistentry>
- <term><replaceable class="parameter">result_rows</replaceable></term>
+ <term><literal>ROWS</literal> <replaceable class="parameter">result_rows</replaceable></term>
<listitem>
<para>
<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.
--- /dev/null
+<!--
+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>
<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>
--- /dev/null
+<!--
+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>
--- /dev/null
+<!--
+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>
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 ] }
<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.
<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>
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>
<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>
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 ]
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> |
<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>
<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>.
<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.
<listitem>
<para>
- The data type of a function or aggregate argument.
+ The data type of a function, procedure, or aggregate argument.
</para>
</listitem>
</varlistentry>
&alterOperatorClass;
&alterOperatorFamily;
&alterPolicy;
+ &alterProcedure;
&alterPublication;
&alterRole;
+ &alterRoutine;
&alterRule;
&alterSchema;
&alterSequence;
&alterView;
&analyze;
&begin;
+ &call;
&checkpoint;
&close;
&cluster;
&createOperatorClass;
&createOperatorFamily;
&createPolicy;
+ &createProcedure;
&createPublication;
&createRole;
&createRule;
&dropOperatorFamily;
&dropOwned;
&dropPolicy;
+ &dropProcedure;
&dropPublication;
&dropRole;
+ &dropRoutine;
&dropRule;
&dropSchema;
&dropSequence;
</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>
all_privileges = ACL_ALL_RIGHTS_NAMESPACE;
errormsg = gettext_noop("invalid privilege type %s for schema");
break;
+ case ACL_OBJECT_PROCEDURE:
+ all_privileges = ACL_ALL_RIGHTS_FUNCTION;
+ errormsg = gettext_noop("invalid privilege type %s for procedure");
+ break;
+ case ACL_OBJECT_ROUTINE:
+ all_privileges = ACL_ALL_RIGHTS_FUNCTION;
+ errormsg = gettext_noop("invalid privilege type %s for routine");
+ break;
case ACL_OBJECT_TABLESPACE:
all_privileges = ACL_ALL_RIGHTS_TABLESPACE;
errormsg = gettext_noop("invalid privilege type %s for tablespace");
ExecGrant_ForeignServer(istmt);
break;
case ACL_OBJECT_FUNCTION:
+ case ACL_OBJECT_PROCEDURE:
+ case ACL_OBJECT_ROUTINE:
ExecGrant_Function(istmt);
break;
case ACL_OBJECT_LANGUAGE:
ObjectWithArgs *func = (ObjectWithArgs *) lfirst(cell);
Oid funcid;
- funcid = LookupFuncWithArgs(func, false);
+ funcid = LookupFuncWithArgs(OBJECT_FUNCTION, func, false);
objects = lappend_oid(objects, funcid);
}
break;
objects = lappend_oid(objects, oid);
}
break;
+ case ACL_OBJECT_PROCEDURE:
+ foreach(cell, objnames)
+ {
+ ObjectWithArgs *func = (ObjectWithArgs *) lfirst(cell);
+ Oid procid;
+
+ procid = LookupFuncWithArgs(OBJECT_PROCEDURE, func, false);
+ objects = lappend_oid(objects, procid);
+ }
+ break;
+ case ACL_OBJECT_ROUTINE:
+ foreach(cell, objnames)
+ {
+ ObjectWithArgs *func = (ObjectWithArgs *) lfirst(cell);
+ Oid routid;
+
+ routid = LookupFuncWithArgs(OBJECT_ROUTINE, func, false);
+ objects = lappend_oid(objects, routid);
+ }
+ break;
case ACL_OBJECT_TABLESPACE:
foreach(cell, objnames)
{
objects = list_concat(objects, objs);
break;
case ACL_OBJECT_FUNCTION:
+ case ACL_OBJECT_PROCEDURE:
+ case ACL_OBJECT_ROUTINE:
{
- ScanKeyData key[1];
+ ScanKeyData key[2];
+ int keycount;
Relation rel;
HeapScanDesc scan;
HeapTuple tuple;
- ScanKeyInit(&key[0],
+ keycount = 0;
+ ScanKeyInit(&key[keycount++],
Anum_pg_proc_pronamespace,
BTEqualStrategyNumber, F_OIDEQ,
ObjectIdGetDatum(namespaceId));
+ /*
+ * When looking for functions, check for return type <>0.
+ * When looking for procedures, check for return type ==0.
+ * When looking for routines, don't check the return type.
+ */
+ if (objtype == ACL_OBJECT_FUNCTION)
+ ScanKeyInit(&key[keycount++],
+ Anum_pg_proc_prorettype,
+ BTEqualStrategyNumber, F_OIDNE,
+ InvalidOid);
+ else if (objtype == ACL_OBJECT_PROCEDURE)
+ ScanKeyInit(&key[keycount++],
+ Anum_pg_proc_prorettype,
+ BTEqualStrategyNumber, F_OIDEQ,
+ InvalidOid);
+
rel = heap_open(ProcedureRelationId, AccessShareLock);
- scan = heap_beginscan_catalog(rel, 1, key);
+ scan = heap_beginscan_catalog(rel, keycount, key);
while ((tuple = heap_getnext(scan, ForwardScanDirection)) != NULL)
{
all_privileges = ACL_ALL_RIGHTS_FUNCTION;
errormsg = gettext_noop("invalid privilege type %s for function");
break;
+ case ACL_OBJECT_PROCEDURE:
+ all_privileges = ACL_ALL_RIGHTS_FUNCTION;
+ errormsg = gettext_noop("invalid privilege type %s for procedure");
+ break;
+ case ACL_OBJECT_ROUTINE:
+ all_privileges = ACL_ALL_RIGHTS_FUNCTION;
+ errormsg = gettext_noop("invalid privilege type %s for routine");
+ break;
case ACL_OBJECT_TYPE:
all_privileges = ACL_ALL_RIGHTS_TYPE;
errormsg = gettext_noop("invalid privilege type %s for type");
istmt.objtype = ACL_OBJECT_TYPE;
break;
case ProcedureRelationId:
- istmt.objtype = ACL_OBJECT_FUNCTION;
+ istmt.objtype = ACL_OBJECT_ROUTINE;
break;
case LanguageRelationId:
istmt.objtype = ACL_OBJECT_LANGUAGE;
CAST(current_database() AS sql_identifier) AS routine_catalog,
CAST(n.nspname AS sql_identifier) AS routine_schema,
CAST(p.proname AS sql_identifier) AS routine_name,
- CAST('FUNCTION' AS character_data) AS routine_type,
+ CAST(CASE WHEN p.prorettype <> 0 THEN 'FUNCTION' ELSE 'PROCEDURE' END
+ AS character_data) AS routine_type,
CAST(null AS sql_identifier) AS module_catalog,
CAST(null AS sql_identifier) AS module_schema,
CAST(null AS sql_identifier) AS module_name,
CAST(null AS sql_identifier) AS udt_name,
CAST(
- CASE WHEN t.typelem <> 0 AND t.typlen = -1 THEN 'ARRAY'
+ CASE WHEN p.prorettype = 0 THEN NULL
+ WHEN t.typelem <> 0 AND t.typlen = -1 THEN 'ARRAY'
WHEN nt.nspname = 'pg_catalog' THEN format_type(t.oid, null)
ELSE 'USER-DEFINED' END AS character_data)
AS data_type,
CAST(null AS cardinal_number) AS datetime_precision,
CAST(null AS character_data) AS interval_type,
CAST(null AS cardinal_number) AS interval_precision,
- CAST(current_database() AS sql_identifier) AS type_udt_catalog,
+ CAST(CASE WHEN p.prorettype <> 0 THEN current_database() END AS sql_identifier) AS type_udt_catalog,
CAST(nt.nspname AS sql_identifier) AS type_udt_schema,
CAST(t.typname AS sql_identifier) AS type_udt_name,
CAST(null AS sql_identifier) AS scope_catalog,
CAST('GENERAL' AS character_data) AS parameter_style,
CAST(CASE WHEN p.provolatile = 'i' THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_deterministic,
CAST('MODIFIES' AS character_data) AS sql_data_access,
- CAST(CASE WHEN p.proisstrict THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_null_call,
+ CAST(CASE WHEN p.prorettype <> 0 THEN
+ CASE WHEN p.proisstrict THEN 'YES' ELSE 'NO' END END AS yes_or_no) AS is_null_call,
CAST(null AS character_data) AS sql_path,
CAST('YES' AS yes_or_no) AS schema_level_routine,
CAST(0 AS cardinal_number) AS max_dynamic_result_sets,
CAST(null AS cardinal_number) AS result_cast_maximum_cardinality,
CAST(null AS sql_identifier) AS result_cast_dtd_identifier
- FROM pg_namespace n, pg_proc p, pg_language l,
- pg_type t, pg_namespace nt
+ FROM (pg_namespace n
+ JOIN pg_proc p ON n.oid = p.pronamespace
+ JOIN pg_language l ON p.prolang = l.oid)
+ LEFT JOIN
+ (pg_type t JOIN pg_namespace nt ON t.typnamespace = nt.oid)
+ ON p.prorettype = t.oid
- WHERE n.oid = p.pronamespace AND p.prolang = l.oid
- AND p.prorettype = t.oid AND t.typnamespace = nt.oid
- AND (pg_has_role(p.proowner, 'USAGE')
- OR has_function_privilege(p.oid, 'EXECUTE'));
+ WHERE (pg_has_role(p.proowner, 'USAGE')
+ OR has_function_privilege(p.oid, 'EXECUTE'));
GRANT SELECT ON routines TO PUBLIC;
{
"function", OBJECT_FUNCTION
},
+ {
+ "procedure", OBJECT_PROCEDURE
+ },
/* OCLASS_TYPE */
{
"type", OBJECT_TYPE
address = get_object_address_type(objtype, castNode(TypeName, object), missing_ok);
break;
case OBJECT_AGGREGATE:
- address.classId = ProcedureRelationId;
- address.objectId = LookupAggWithArgs(castNode(ObjectWithArgs, object), missing_ok);
- address.objectSubId = 0;
- break;
case OBJECT_FUNCTION:
+ case OBJECT_PROCEDURE:
+ case OBJECT_ROUTINE:
address.classId = ProcedureRelationId;
- address.objectId = LookupFuncWithArgs(castNode(ObjectWithArgs, object), missing_ok);
+ address.objectId = LookupFuncWithArgs(objtype, castNode(ObjectWithArgs, object), missing_ok);
address.objectSubId = 0;
break;
case OBJECT_OPERATOR:
*/
if (type == OBJECT_AGGREGATE ||
type == OBJECT_FUNCTION ||
+ type == OBJECT_PROCEDURE ||
+ type == OBJECT_ROUTINE ||
type == OBJECT_OPERATOR ||
type == OBJECT_CAST ||
type == OBJECT_AMOP ||
objnode = (Node *) list_make2(name, args);
break;
case OBJECT_FUNCTION:
+ case OBJECT_PROCEDURE:
+ case OBJECT_ROUTINE:
case OBJECT_AGGREGATE:
case OBJECT_OPERATOR:
{
break;
case OBJECT_AGGREGATE:
case OBJECT_FUNCTION:
+ case OBJECT_PROCEDURE:
+ case OBJECT_ROUTINE:
if (!pg_proc_ownercheck(address.objectId, roleid))
aclcheck_error(ACLCHECK_NOT_OWNER, ACL_KIND_PROC,
NameListToString((castNode(ObjectWithArgs, object))->objname));
if (procForm->proisagg)
appendStringInfoString(buffer, "aggregate");
+ else if (procForm->prorettype == InvalidOid)
+ appendStringInfoString(buffer, "procedure");
else
appendStringInfoString(buffer, "function");
/* Disallow pseudotype result */
/* except for RECORD, VOID, or polymorphic */
- if (get_typtype(proc->prorettype) == TYPTYPE_PSEUDO &&
+ if (proc->prorettype &&
+ get_typtype(proc->prorettype) == TYPTYPE_PSEUDO &&
proc->prorettype != RECORDOID &&
proc->prorettype != VOIDOID &&
!IsPolymorphicType(proc->prorettype))
interpret_function_parameter_list(pstate,
args,
InvalidOid,
- true, /* is an aggregate */
+ OBJECT_AGGREGATE,
¶meterTypes,
&allParameterTypes,
¶meterModes,
case OBJECT_OPCLASS:
case OBJECT_OPFAMILY:
case OBJECT_LANGUAGE:
+ case OBJECT_PROCEDURE:
+ case OBJECT_ROUTINE:
case OBJECT_STATISTIC_EXT:
case OBJECT_TSCONFIGURATION:
case OBJECT_TSDICTIONARY:
case OBJECT_OPERATOR:
case OBJECT_OPCLASS:
case OBJECT_OPFAMILY:
+ case OBJECT_PROCEDURE:
+ case OBJECT_ROUTINE:
case OBJECT_STATISTIC_EXT:
case OBJECT_TSCONFIGURATION:
case OBJECT_TSDICTIONARY:
case OBJECT_OPERATOR:
case OBJECT_OPCLASS:
case OBJECT_OPFAMILY:
+ case OBJECT_PROCEDURE:
+ case OBJECT_ROUTINE:
case OBJECT_STATISTIC_EXT:
case OBJECT_TABLESPACE:
case OBJECT_TSDICTIONARY:
#include "nodes/makefuncs.h"
#include "parser/parse_type.h"
#include "utils/builtins.h"
+#include "utils/lsyscache.h"
#include "utils/syscache.h"
*/
if (stmt->removeType == OBJECT_FUNCTION)
{
- Oid funcOid = address.objectId;
- HeapTuple tup;
-
- tup = SearchSysCache1(PROCOID, ObjectIdGetDatum(funcOid));
- if (!HeapTupleIsValid(tup)) /* should not happen */
- elog(ERROR, "cache lookup failed for function %u", funcOid);
-
- if (((Form_pg_proc) GETSTRUCT(tup))->proisagg)
+ if (get_func_isagg(address.objectId))
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("\"%s\" is an aggregate function",
NameListToString(castNode(ObjectWithArgs, object)->objname)),
errhint("Use DROP AGGREGATE to drop aggregate functions.")));
-
- ReleaseSysCache(tup);
}
/* Check permissions. */
}
break;
}
+ case OBJECT_PROCEDURE:
+ {
+ ObjectWithArgs *owa = castNode(ObjectWithArgs, object);
+
+ if (!schema_does_not_exist_skipping(owa->objname, &msg, &name) &&
+ !type_in_list_does_not_exist_skipping(owa->objargs, &msg, &name))
+ {
+ msg = gettext_noop("procedure %s(%s) does not exist, skipping");
+ name = NameListToString(owa->objname);
+ args = TypeNameListToString(owa->objargs);
+ }
+ break;
+ }
+ case OBJECT_ROUTINE:
+ {
+ ObjectWithArgs *owa = castNode(ObjectWithArgs, object);
+
+ if (!schema_does_not_exist_skipping(owa->objname, &msg, &name) &&
+ !type_in_list_does_not_exist_skipping(owa->objargs, &msg, &name))
+ {
+ msg = gettext_noop("routine %s(%s) does not exist, skipping");
+ name = NameListToString(owa->objname);
+ args = TypeNameListToString(owa->objargs);
+ }
+ break;
+ }
case OBJECT_AGGREGATE:
{
ObjectWithArgs *owa = castNode(ObjectWithArgs, object);
{"OPERATOR CLASS", true},
{"OPERATOR FAMILY", true},
{"POLICY", true},
+ {"PROCEDURE", true},
{"PUBLICATION", true},
{"ROLE", false},
+ {"ROUTINE", true},
{"RULE", true},
{"SCHEMA", true},
{"SEQUENCE", true},
case OBJECT_OPERATOR:
case OBJECT_OPFAMILY:
case OBJECT_POLICY:
+ case OBJECT_PROCEDURE:
case OBJECT_PUBLICATION:
case OBJECT_PUBLICATION_REL:
+ case OBJECT_ROUTINE:
case OBJECT_RULE:
case OBJECT_SCHEMA:
case OBJECT_SEQUENCE:
case ACL_OBJECT_LANGUAGE:
case ACL_OBJECT_LARGEOBJECT:
case ACL_OBJECT_NAMESPACE:
+ case ACL_OBJECT_PROCEDURE:
+ case ACL_OBJECT_ROUTINE:
case ACL_OBJECT_TYPE:
return true;
return "LARGE OBJECT";
case ACL_OBJECT_NAMESPACE:
return "SCHEMA";
+ case ACL_OBJECT_PROCEDURE:
+ return "PROCEDURE";
+ case ACL_OBJECT_ROUTINE:
+ return "ROUTINE";
case ACL_OBJECT_TABLESPACE:
return "TABLESPACE";
case ACL_OBJECT_TYPE:
return "LARGE OBJECTS";
case ACL_OBJECT_NAMESPACE:
return "SCHEMAS";
+ case ACL_OBJECT_PROCEDURE:
+ return "PROCEDURES";
+ case ACL_OBJECT_ROUTINE:
+ return "ROUTINES";
case ACL_OBJECT_TABLESPACE:
return "TABLESPACES";
case ACL_OBJECT_TYPE:
#include "commands/alter.h"
#include "commands/defrem.h"
#include "commands/proclang.h"
+#include "executor/execdesc.h"
+#include "executor/executor.h"
#include "miscadmin.h"
#include "optimizer/var.h"
#include "parser/parse_coerce.h"
interpret_function_parameter_list(ParseState *pstate,
List *parameters,
Oid languageOid,
- bool is_aggregate,
+ ObjectType objtype,
oidvector **parameterTypes,
ArrayType **allParameterTypes,
ArrayType **parameterModes,
errmsg("SQL function cannot accept shell type %s",
TypeNameToString(t))));
/* We don't allow creating aggregates on shell types either */
- else if (is_aggregate)
+ else if (objtype == OBJECT_AGGREGATE)
ereport(ERROR,
(errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
errmsg("aggregate cannot accept shell type %s",
if (t->setof)
{
- if (is_aggregate)
+ if (objtype == OBJECT_AGGREGATE)
ereport(ERROR,
(errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
errmsg("aggregates cannot accept set arguments")));
+ else if (objtype == OBJECT_PROCEDURE)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
+ errmsg("procedures cannot accept set arguments")));
else
ereport(ERROR,
(errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
errmsg("functions cannot accept set arguments")));
}
+ if (objtype == OBJECT_PROCEDURE)
+ {
+ if (fp->mode == FUNC_PARAM_OUT || fp->mode == FUNC_PARAM_INOUT)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ (errmsg("procedures cannot have OUT parameters"))));
+ }
+
/* handle input parameters */
if (fp->mode != FUNC_PARAM_OUT && fp->mode != FUNC_PARAM_TABLE)
{
*/
static bool
compute_common_attribute(ParseState *pstate,
+ bool is_procedure,
DefElem *defel,
DefElem **volatility_item,
DefElem **strict_item,
{
if (strcmp(defel->defname, "volatility") == 0)
{
+ if (is_procedure)
+ goto procedure_error;
if (*volatility_item)
goto duplicate_error;
}
else if (strcmp(defel->defname, "strict") == 0)
{
+ if (is_procedure)
+ goto procedure_error;
if (*strict_item)
goto duplicate_error;
}
else if (strcmp(defel->defname, "leakproof") == 0)
{
+ if (is_procedure)
+ goto procedure_error;
if (*leakproof_item)
goto duplicate_error;
}
else if (strcmp(defel->defname, "cost") == 0)
{
+ if (is_procedure)
+ goto procedure_error;
if (*cost_item)
goto duplicate_error;
}
else if (strcmp(defel->defname, "rows") == 0)
{
+ if (is_procedure)
+ goto procedure_error;
if (*rows_item)
goto duplicate_error;
}
else if (strcmp(defel->defname, "parallel") == 0)
{
+ if (is_procedure)
+ goto procedure_error;
if (*parallel_item)
goto duplicate_error;
errmsg("conflicting or redundant options"),
parser_errposition(pstate, defel->location)));
return false; /* keep compiler quiet */
+
+procedure_error:
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
+ errmsg("invalid attribute in procedure definition"),
+ parser_errposition(pstate, defel->location)));
+ return false;
}
static char
*/
static void
compute_attributes_sql_style(ParseState *pstate,
+ bool is_procedure,
List *options,
List **as,
char **language,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("conflicting or redundant options"),
parser_errposition(pstate, defel->location)));
+ if (is_procedure)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
+ errmsg("invalid attribute in procedure definition"),
+ parser_errposition(pstate, defel->location)));
windowfunc_item = defel;
}
else if (compute_common_attribute(pstate,
+ is_procedure,
defel,
&volatility_item,
&strict_item,
*------------
*/
static void
-compute_attributes_with_style(ParseState *pstate, List *parameters, bool *isStrict_p, char *volatility_p)
+compute_attributes_with_style(ParseState *pstate, bool is_procedure, List *parameters, bool *isStrict_p, char *volatility_p)
{
ListCell *pl;
DefElem *param = (DefElem *) lfirst(pl);
if (pg_strcasecmp(param->defname, "isstrict") == 0)
+ {
+ if (is_procedure)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
+ errmsg("invalid attribute in procedure definition"),
+ parser_errposition(pstate, param->location)));
*isStrict_p = defGetBoolean(param);
+ }
else if (pg_strcasecmp(param->defname, "iscachable") == 0)
{
/* obsolete spelling of isImmutable */
+ if (is_procedure)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
+ errmsg("invalid attribute in procedure definition"),
+ parser_errposition(pstate, param->location)));
if (defGetBoolean(param))
*volatility_p = PROVOLATILE_IMMUTABLE;
}
/* override attributes from explicit list */
compute_attributes_sql_style(pstate,
+ stmt->is_procedure,
stmt->options,
&as_clause, &language, &transformDefElem,
&isWindowFunc, &volatility,
interpret_function_parameter_list(pstate,
stmt->parameters,
languageOid,
- false, /* not an aggregate */
+ stmt->is_procedure ? OBJECT_PROCEDURE : OBJECT_FUNCTION,
¶meterTypes,
&allParameterTypes,
¶meterModes,
&variadicArgType,
&requiredResultType);
- if (stmt->returnType)
+ if (stmt->is_procedure)
+ {
+ Assert(!stmt->returnType);
+
+ prorettype = InvalidOid;
+ returnsSet = false;
+ }
+ else if (stmt->returnType)
{
/* explicit RETURNS clause */
compute_return_type(stmt->returnType, languageOid,
trftypes = NULL;
}
- compute_attributes_with_style(pstate, stmt->withClause, &isStrict, &volatility);
+ compute_attributes_with_style(pstate, stmt->is_procedure, stmt->withClause, &isStrict, &volatility);
interpret_AS_clause(languageOid, language, funcname, as_clause,
&prosrc_str, &probin_str);
HeapTuple tup;
Oid funcOid;
Form_pg_proc procForm;
+ bool is_procedure;
Relation rel;
ListCell *l;
DefElem *volatility_item = NULL;
rel = heap_open(ProcedureRelationId, RowExclusiveLock);
- funcOid = LookupFuncWithArgs(stmt->func, false);
+ funcOid = LookupFuncWithArgs(stmt->objtype, stmt->func, false);
tup = SearchSysCacheCopy1(PROCOID, ObjectIdGetDatum(funcOid));
if (!HeapTupleIsValid(tup)) /* should not happen */
errmsg("\"%s\" is an aggregate function",
NameListToString(stmt->func->objname))));
+ is_procedure = (procForm->prorettype == InvalidOid);
+
/* Examine requested actions. */
foreach(l, stmt->actions)
{
DefElem *defel = (DefElem *) lfirst(l);
if (compute_common_attribute(pstate,
+ is_procedure,
defel,
&volatility_item,
&strict_item,
{
Form_pg_proc procstruct;
- funcid = LookupFuncWithArgs(stmt->func, false);
+ funcid = LookupFuncWithArgs(OBJECT_FUNCTION, stmt->func, false);
tuple = SearchSysCache1(PROCOID, ObjectIdGetDatum(funcid));
if (!HeapTupleIsValid(tuple))
*/
if (stmt->fromsql)
{
- fromsqlfuncid = LookupFuncWithArgs(stmt->fromsql, false);
+ fromsqlfuncid = LookupFuncWithArgs(OBJECT_FUNCTION, stmt->fromsql, false);
if (!pg_proc_ownercheck(fromsqlfuncid, GetUserId()))
aclcheck_error(ACLCHECK_NOT_OWNER, ACL_KIND_PROC, NameListToString(stmt->fromsql->objname));
if (stmt->tosql)
{
- tosqlfuncid = LookupFuncWithArgs(stmt->tosql, false);
+ tosqlfuncid = LookupFuncWithArgs(OBJECT_FUNCTION, stmt->tosql, false);
if (!pg_proc_ownercheck(tosqlfuncid, GetUserId()))
aclcheck_error(ACLCHECK_NOT_OWNER, ACL_KIND_PROC, NameListToString(stmt->tosql->objname));
/* execute the inline handler */
OidFunctionCall1(laninline, PointerGetDatum(codeblock));
}
+
+/*
+ * Execute CALL statement
+ */
+void
+ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
+{
+ List *targs;
+ ListCell *lc;
+ Node *node;
+ FuncExpr *fexpr;
+ int nargs;
+ int i;
+ AclResult aclresult;
+ FmgrInfo flinfo;
+ FunctionCallInfoData fcinfo;
+
+ targs = NIL;
+ foreach(lc, stmt->funccall->args)
+ {
+ targs = lappend(targs, transformExpr(pstate,
+ (Node *) lfirst(lc),
+ EXPR_KIND_CALL));
+ }
+
+ node = ParseFuncOrColumn(pstate,
+ stmt->funccall->funcname,
+ targs,
+ pstate->p_last_srf,
+ stmt->funccall,
+ true,
+ stmt->funccall->location);
+
+ fexpr = castNode(FuncExpr, node);
+
+ aclresult = pg_proc_aclcheck(fexpr->funcid, GetUserId(), ACL_EXECUTE);
+ if (aclresult != ACLCHECK_OK)
+ aclcheck_error(aclresult, ACL_KIND_PROC, get_func_name(fexpr->funcid));
+ InvokeFunctionExecuteHook(fexpr->funcid);
+
+ nargs = list_length(fexpr->args);
+
+ /* safety check; see ExecInitFunc() */
+ if (nargs > FUNC_MAX_ARGS)
+ ereport(ERROR,
+ (errcode(ERRCODE_TOO_MANY_ARGUMENTS),
+ errmsg_plural("cannot pass more than %d argument to a procedure",
+ "cannot pass more than %d arguments to a procedure",
+ FUNC_MAX_ARGS,
+ FUNC_MAX_ARGS)));
+
+ fmgr_info(fexpr->funcid, &flinfo);
+ InitFunctionCallInfoData(fcinfo, &flinfo, nargs, fexpr->inputcollid, NULL, NULL);
+
+ i = 0;
+ foreach (lc, fexpr->args)
+ {
+ EState *estate;
+ ExprState *exprstate;
+ ExprContext *econtext;
+ Datum val;
+ bool isnull;
+
+ estate = CreateExecutorState();
+ exprstate = ExecPrepareExpr(lfirst(lc), estate);
+ econtext = CreateStandaloneExprContext();
+ val = ExecEvalExprSwitchContext(exprstate, econtext, &isnull);
+ FreeExecutorState(estate);
+
+ fcinfo.arg[i] = val;
+ fcinfo.argnull[i] = isnull;
+
+ i++;
+ }
+
+ FunctionCallInvoke(&fcinfo);
+}
errmsg("invalid procedure number %d,"
" must be between 1 and %d",
item->number, maxProcNumber)));
- funcOid = LookupFuncWithArgs(item->name, false);
+ funcOid = LookupFuncWithArgs(OBJECT_FUNCTION, item->name, false);
#ifdef NOT_USED
/* XXX this is unnecessary given the superuser check above */
/* Caller must own function */
errmsg("invalid procedure number %d,"
" must be between 1 and %d",
item->number, maxProcNumber)));
- funcOid = LookupFuncWithArgs(item->name, false);
+ funcOid = LookupFuncWithArgs(OBJECT_FUNCTION, item->name, false);
#ifdef NOT_USED
/* XXX this is unnecessary given the superuser check above */
/* Caller must own function */
list_make1(param),
pstate->p_last_srf,
NULL,
+ false,
cref->location);
}
fcache->rettype = rettype;
/* Fetch the typlen and byval info for the result type */
- get_typlenbyval(rettype, &fcache->typlen, &fcache->typbyval);
+ if (rettype)
+ get_typlenbyval(rettype, &fcache->typlen, &fcache->typbyval);
/* Remember whether we're returning setof something */
fcache->returnsSet = procedureStruct->proretset;
}
else
{
- /* Should only get here for VOID functions */
- Assert(fcache->rettype == VOIDOID);
+ /* Should only get here for procedures and VOID functions */
+ Assert(fcache->rettype == InvalidOid || fcache->rettype == VOIDOID);
fcinfo->isnull = true;
result = (Datum) 0;
}
if (modifyTargetList)
*modifyTargetList = false; /* initialize for no change */
if (junkFilter)
- *junkFilter = NULL; /* initialize in case of VOID result */
+ *junkFilter = NULL; /* initialize in case of procedure/VOID result */
+
+ if (!rettype)
+ return false;
/*
* Find the last canSetTag query in the list. This isn't necessarily the
else
{
/* Empty function body, or last statement is a utility command */
- if (rettype != VOIDOID)
+ if (rettype && rettype != VOIDOID)
ereport(ERROR,
(errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
errmsg("return type mismatch in function declared to return %s",
return newnode;
}
+static CallStmt *
+_copyCallStmt(const CallStmt *from)
+{
+ CallStmt *newnode = makeNode(CallStmt);
+
+ COPY_NODE_FIELD(funccall);
+
+ return newnode;
+}
+
static ClusterStmt *
_copyClusterStmt(const ClusterStmt *from)
{
COPY_NODE_FIELD(funcname);
COPY_NODE_FIELD(parameters);
COPY_NODE_FIELD(returnType);
+ COPY_SCALAR_FIELD(is_procedure);
COPY_NODE_FIELD(options);
COPY_NODE_FIELD(withClause);
{
AlterFunctionStmt *newnode = makeNode(AlterFunctionStmt);
+ COPY_SCALAR_FIELD(objtype);
COPY_NODE_FIELD(func);
COPY_NODE_FIELD(actions);
case T_ClosePortalStmt:
retval = _copyClosePortalStmt(from);
break;
+ case T_CallStmt:
+ retval = _copyCallStmt(from);
+ break;
case T_ClusterStmt:
retval = _copyClusterStmt(from);
break;
return true;
}
+static bool
+_equalCallStmt(const CallStmt *a, const CallStmt *b)
+{
+ COMPARE_NODE_FIELD(funccall);
+
+ return true;
+}
+
static bool
_equalClusterStmt(const ClusterStmt *a, const ClusterStmt *b)
{
COMPARE_NODE_FIELD(funcname);
COMPARE_NODE_FIELD(parameters);
COMPARE_NODE_FIELD(returnType);
+ COMPARE_SCALAR_FIELD(is_procedure);
COMPARE_NODE_FIELD(options);
COMPARE_NODE_FIELD(withClause);
static bool
_equalAlterFunctionStmt(const AlterFunctionStmt *a, const AlterFunctionStmt *b)
{
+ COMPARE_SCALAR_FIELD(objtype);
COMPARE_NODE_FIELD(func);
COMPARE_NODE_FIELD(actions);
case T_ClosePortalStmt:
retval = _equalClosePortalStmt(a, b);
break;
+ case T_CallStmt:
+ retval = _equalCallStmt(a, b);
+ break;
case T_ClusterStmt:
retval = _equalClusterStmt(a, b);
break;
if (funcform->prolang != SQLlanguageId ||
funcform->prosecdef ||
funcform->proretset ||
+ funcform->prorettype == InvalidOid ||
funcform->prorettype == RECORDOID ||
!heap_attisnull(func_tuple, Anum_pg_proc_proconfig) ||
funcform->pronargs != list_length(args))
AlterCompositeTypeStmt AlterUserMappingStmt
AlterRoleStmt AlterRoleSetStmt AlterPolicyStmt
AlterDefaultPrivilegesStmt DefACLAction
- AnalyzeStmt ClosePortalStmt ClusterStmt CommentStmt
+ AnalyzeStmt CallStmt ClosePortalStmt ClusterStmt CommentStmt
ConstraintsSetStmt CopyStmt CreateAsStmt CreateCastStmt
CreateDomainStmt CreateExtensionStmt CreateGroupStmt CreateOpClassStmt
CreateOpFamilyStmt AlterOpFamilyStmt CreatePLangStmt
BACKWARD BEFORE BEGIN_P BETWEEN BIGINT BINARY BIT
BOOLEAN_P BOTH BY
- CACHE CALLED CASCADE CASCADED CASE CAST CATALOG_P CHAIN CHAR_P
+ CACHE CALL CALLED CASCADE CASCADED CASE CAST CATALOG_P CHAIN CHAR_P
CHARACTER CHARACTERISTICS CHECK CHECKPOINT CLASS CLOSE
CLUSTER COALESCE COLLATE COLLATION COLUMN COLUMNS COMMENT COMMENTS COMMIT
COMMITTED CONCURRENTLY CONFIGURATION CONFLICT CONNECTION CONSTRAINT
PARALLEL PARSER PARTIAL PARTITION PASSING PASSWORD PLACING PLANS POLICY
POSITION PRECEDING PRECISION PRESERVE PREPARE PREPARED PRIMARY
- PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROGRAM PUBLICATION
+ PRIOR PRIVILEGES PROCEDURAL PROCEDURE PROCEDURES PROGRAM PUBLICATION
QUOTE
RANGE READ REAL REASSIGN RECHECK RECURSIVE REF REFERENCES REFERENCING
REFRESH REINDEX RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA
RESET RESTART RESTRICT RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROLLUP
- ROW ROWS RULE
+ ROUTINE ROUTINES ROW ROWS RULE
SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES
SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHOW
| AlterTSDictionaryStmt
| AlterUserMappingStmt
| AnalyzeStmt
+ | CallStmt
| CheckPointStmt
| ClosePortalStmt
| ClusterStmt
{ $$ = NULL; }
;
+/*****************************************************************************
+ *
+ * CALL statement
+ *
+ *****************************************************************************/
+
+CallStmt: CALL func_application
+ {
+ CallStmt *n = makeNode(CallStmt);
+ n->funccall = castNode(FuncCall, $2);
+ $$ = (Node *)n;
+ }
+ ;
+
/*****************************************************************************
*
* Create a new Postgres DBMS role
n->object = (Node *) lcons(makeString($9), $7);
$$ = (Node *)n;
}
+ | ALTER EXTENSION name add_drop PROCEDURE function_with_argtypes
+ {
+ AlterExtensionContentsStmt *n = makeNode(AlterExtensionContentsStmt);
+ n->extname = $3;
+ n->action = $4;
+ n->objtype = OBJECT_PROCEDURE;
+ n->object = (Node *) $6;
+ $$ = (Node *)n;
+ }
+ | ALTER EXTENSION name add_drop ROUTINE function_with_argtypes
+ {
+ AlterExtensionContentsStmt *n = makeNode(AlterExtensionContentsStmt);
+ n->extname = $3;
+ n->action = $4;
+ n->objtype = OBJECT_ROUTINE;
+ n->object = (Node *) $6;
+ $$ = (Node *)n;
+ }
| ALTER EXTENSION name add_drop SCHEMA name
{
AlterExtensionContentsStmt *n = makeNode(AlterExtensionContentsStmt);
n->comment = $8;
$$ = (Node *) n;
}
+ | COMMENT ON PROCEDURE function_with_argtypes IS comment_text
+ {
+ CommentStmt *n = makeNode(CommentStmt);
+ n->objtype = OBJECT_PROCEDURE;
+ n->object = (Node *) $4;
+ n->comment = $6;
+ $$ = (Node *) n;
+ }
+ | COMMENT ON ROUTINE function_with_argtypes IS comment_text
+ {
+ CommentStmt *n = makeNode(CommentStmt);
+ n->objtype = OBJECT_ROUTINE;
+ n->object = (Node *) $4;
+ n->comment = $6;
+ $$ = (Node *) n;
+ }
| COMMENT ON RULE name ON any_name IS comment_text
{
CommentStmt *n = makeNode(CommentStmt);
n->label = $9;
$$ = (Node *) n;
}
+ | SECURITY LABEL opt_provider ON PROCEDURE function_with_argtypes
+ IS security_label
+ {
+ SecLabelStmt *n = makeNode(SecLabelStmt);
+ n->provider = $3;
+ n->objtype = OBJECT_PROCEDURE;
+ n->object = (Node *) $6;
+ n->label = $8;
+ $$ = (Node *) n;
+ }
+ | SECURITY LABEL opt_provider ON ROUTINE function_with_argtypes
+ IS security_label
+ {
+ SecLabelStmt *n = makeNode(SecLabelStmt);
+ n->provider = $3;
+ n->objtype = OBJECT_ROUTINE;
+ n->object = (Node *) $6;
+ n->label = $8;
+ $$ = (Node *) n;
+ }
;
opt_provider: FOR NonReservedWord_or_Sconst { $$ = $2; }
n->objs = $2;
$$ = n;
}
+ | PROCEDURE function_with_argtypes_list
+ {
+ PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget));
+ n->targtype = ACL_TARGET_OBJECT;
+ n->objtype = ACL_OBJECT_PROCEDURE;
+ n->objs = $2;
+ $$ = n;
+ }
+ | ROUTINE function_with_argtypes_list
+ {
+ PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget));
+ n->targtype = ACL_TARGET_OBJECT;
+ n->objtype = ACL_OBJECT_ROUTINE;
+ n->objs = $2;
+ $$ = n;
+ }
| DATABASE name_list
{
PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget));
n->objs = $5;
$$ = n;
}
+ | ALL PROCEDURES IN_P SCHEMA name_list
+ {
+ PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget));
+ n->targtype = ACL_TARGET_ALL_IN_SCHEMA;
+ n->objtype = ACL_OBJECT_PROCEDURE;
+ n->objs = $5;
+ $$ = n;
+ }
+ | ALL ROUTINES IN_P SCHEMA name_list
+ {
+ PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget));
+ n->targtype = ACL_TARGET_ALL_IN_SCHEMA;
+ n->objtype = ACL_OBJECT_ROUTINE;
+ n->objs = $5;
+ $$ = n;
+ }
;
defacl_privilege_target:
TABLES { $$ = ACL_OBJECT_RELATION; }
| FUNCTIONS { $$ = ACL_OBJECT_FUNCTION; }
+ | ROUTINES { $$ = ACL_OBJECT_FUNCTION; }
| SEQUENCES { $$ = ACL_OBJECT_SEQUENCE; }
| TYPES_P { $$ = ACL_OBJECT_TYPE; }
| SCHEMAS { $$ = ACL_OBJECT_NAMESPACE; }
n->withClause = $7;
$$ = (Node *)n;
}
+ | CREATE opt_or_replace PROCEDURE func_name func_args_with_defaults
+ createfunc_opt_list
+ {
+ CreateFunctionStmt *n = makeNode(CreateFunctionStmt);
+ n->replace = $2;
+ n->funcname = $4;
+ n->parameters = $5;
+ n->returnType = NULL;
+ n->is_procedure = true;
+ n->options = $6;
+ $$ = (Node *)n;
+ }
;
opt_or_replace:
;
/*****************************************************************************
- * ALTER FUNCTION
+ * ALTER FUNCTION / ALTER PROCEDURE / ALTER ROUTINE
*
* RENAME and OWNER subcommands are already provided by the generic
* ALTER infrastructure, here we just specify alterations that can
ALTER FUNCTION function_with_argtypes alterfunc_opt_list opt_restrict
{
AlterFunctionStmt *n = makeNode(AlterFunctionStmt);
+ n->objtype = OBJECT_FUNCTION;
+ n->func = $3;
+ n->actions = $4;
+ $$ = (Node *) n;
+ }
+ | ALTER PROCEDURE function_with_argtypes alterfunc_opt_list opt_restrict
+ {
+ AlterFunctionStmt *n = makeNode(AlterFunctionStmt);
+ n->objtype = OBJECT_PROCEDURE;
+ n->func = $3;
+ n->actions = $4;
+ $$ = (Node *) n;
+ }
+ | ALTER ROUTINE function_with_argtypes alterfunc_opt_list opt_restrict
+ {
+ AlterFunctionStmt *n = makeNode(AlterFunctionStmt);
+ n->objtype = OBJECT_ROUTINE;
n->func = $3;
n->actions = $4;
$$ = (Node *) n;
* QUERY:
*
* DROP FUNCTION funcname (arg1, arg2, ...) [ RESTRICT | CASCADE ]
+ * DROP PROCEDURE procname (arg1, arg2, ...) [ RESTRICT | CASCADE ]
+ * DROP ROUTINE routname (arg1, arg2, ...) [ RESTRICT | CASCADE ]
* DROP AGGREGATE aggname (arg1, ...) [ RESTRICT | CASCADE ]
* DROP OPERATOR opname (leftoperand_typ, rightoperand_typ) [ RESTRICT | CASCADE ]
*
n->concurrent = false;
$$ = (Node *)n;
}
+ | DROP PROCEDURE function_with_argtypes_list opt_drop_behavior
+ {
+ DropStmt *n = makeNode(DropStmt);
+ n->removeType = OBJECT_PROCEDURE;
+ n->objects = $3;
+ n->behavior = $4;
+ n->missing_ok = false;
+ n->concurrent = false;
+ $$ = (Node *)n;
+ }
+ | DROP PROCEDURE IF_P EXISTS function_with_argtypes_list opt_drop_behavior
+ {
+ DropStmt *n = makeNode(DropStmt);
+ n->removeType = OBJECT_PROCEDURE;
+ n->objects = $5;
+ n->behavior = $6;
+ n->missing_ok = true;
+ n->concurrent = false;
+ $$ = (Node *)n;
+ }
+ | DROP ROUTINE function_with_argtypes_list opt_drop_behavior
+ {
+ DropStmt *n = makeNode(DropStmt);
+ n->removeType = OBJECT_ROUTINE;
+ n->objects = $3;
+ n->behavior = $4;
+ n->missing_ok = false;
+ n->concurrent = false;
+ $$ = (Node *)n;
+ }
+ | DROP ROUTINE IF_P EXISTS function_with_argtypes_list opt_drop_behavior
+ {
+ DropStmt *n = makeNode(DropStmt);
+ n->removeType = OBJECT_ROUTINE;
+ n->objects = $5;
+ n->behavior = $6;
+ n->missing_ok = true;
+ n->concurrent = false;
+ $$ = (Node *)n;
+ }
;
RemoveAggrStmt:
n->missing_ok = true;
$$ = (Node *)n;
}
+ | ALTER PROCEDURE function_with_argtypes RENAME TO name
+ {
+ RenameStmt *n = makeNode(RenameStmt);
+ n->renameType = OBJECT_PROCEDURE;
+ n->object = (Node *) $3;
+ n->newname = $6;
+ n->missing_ok = false;
+ $$ = (Node *)n;
+ }
| ALTER PUBLICATION name RENAME TO name
{
RenameStmt *n = makeNode(RenameStmt);
n->missing_ok = false;
$$ = (Node *)n;
}
+ | ALTER ROUTINE function_with_argtypes RENAME TO name
+ {
+ RenameStmt *n = makeNode(RenameStmt);
+ n->renameType = OBJECT_ROUTINE;
+ n->object = (Node *) $3;
+ n->newname = $6;
+ n->missing_ok = false;
+ $$ = (Node *)n;
+ }
| ALTER SCHEMA name RENAME TO name
{
RenameStmt *n = makeNode(RenameStmt);
n->extname = makeString($7);
$$ = (Node *)n;
}
+ | ALTER PROCEDURE function_with_argtypes DEPENDS ON EXTENSION name
+ {
+ AlterObjectDependsStmt *n = makeNode(AlterObjectDependsStmt);
+ n->objectType = OBJECT_PROCEDURE;
+ n->object = (Node *) $3;
+ n->extname = makeString($7);
+ $$ = (Node *)n;
+ }
+ | ALTER ROUTINE function_with_argtypes DEPENDS ON EXTENSION name
+ {
+ AlterObjectDependsStmt *n = makeNode(AlterObjectDependsStmt);
+ n->objectType = OBJECT_ROUTINE;
+ n->object = (Node *) $3;
+ n->extname = makeString($7);
+ $$ = (Node *)n;
+ }
| ALTER TRIGGER name ON qualified_name DEPENDS ON EXTENSION name
{
AlterObjectDependsStmt *n = makeNode(AlterObjectDependsStmt);
n->missing_ok = false;
$$ = (Node *)n;
}
+ | ALTER PROCEDURE function_with_argtypes SET SCHEMA name
+ {
+ AlterObjectSchemaStmt *n = makeNode(AlterObjectSchemaStmt);
+ n->objectType = OBJECT_PROCEDURE;
+ n->object = (Node *) $3;
+ n->newschema = $6;
+ n->missing_ok = false;
+ $$ = (Node *)n;
+ }
+ | ALTER ROUTINE function_with_argtypes SET SCHEMA name
+ {
+ AlterObjectSchemaStmt *n = makeNode(AlterObjectSchemaStmt);
+ n->objectType = OBJECT_ROUTINE;
+ n->object = (Node *) $3;
+ n->newschema = $6;
+ n->missing_ok = false;
+ $$ = (Node *)n;
+ }
| ALTER TABLE relation_expr SET SCHEMA name
{
AlterObjectSchemaStmt *n = makeNode(AlterObjectSchemaStmt);
n->newowner = $9;
$$ = (Node *)n;
}
+ | ALTER PROCEDURE function_with_argtypes OWNER TO RoleSpec
+ {
+ AlterOwnerStmt *n = makeNode(AlterOwnerStmt);
+ n->objectType = OBJECT_PROCEDURE;
+ n->object = (Node *) $3;
+ n->newowner = $6;
+ $$ = (Node *)n;
+ }
+ | ALTER ROUTINE function_with_argtypes OWNER TO RoleSpec
+ {
+ AlterOwnerStmt *n = makeNode(AlterOwnerStmt);
+ n->objectType = OBJECT_ROUTINE;
+ n->object = (Node *) $3;
+ n->newowner = $6;
+ $$ = (Node *)n;
+ }
| ALTER SCHEMA name OWNER TO RoleSpec
{
AlterOwnerStmt *n = makeNode(AlterOwnerStmt);
| BEGIN_P
| BY
| CACHE
+ | CALL
| CALLED
| CASCADE
| CASCADED
| PRIVILEGES
| PROCEDURAL
| PROCEDURE
+ | PROCEDURES
| PROGRAM
| PUBLICATION
| QUOTE
| ROLE
| ROLLBACK
| ROLLUP
+ | ROUTINE
+ | ROUTINES
| ROWS
| RULE
| SAVEPOINT
break;
+ case EXPR_KIND_CALL:
+ if (isAgg)
+ err = _("aggregate functions are not allowed in CALL arguments");
+ else
+ err = _("grouping operations are not allowed in CALL arguments");
+
+ break;
+
/*
* There is intentionally no default: case here, so that the
* compiler will warn if we add a new ParseExprKind without
case EXPR_KIND_PARTITION_EXPRESSION:
err = _("window functions are not allowed in partition key expression");
break;
+ case EXPR_KIND_CALL:
+ err = _("window functions are not allowed in CALL arguments");
+ break;
/*
* There is intentionally no default: case here, so that the
list_make1(result),
last_srf,
NULL,
+ false,
location);
if (newresult == NULL)
unknown_attribute(pstate, result, strVal(n), location);
list_make1(node),
pstate->p_last_srf,
NULL,
+ false,
cref->location);
}
break;
list_make1(node),
pstate->p_last_srf,
NULL,
+ false,
cref->location);
}
break;
list_make1(node),
pstate->p_last_srf,
NULL,
+ false,
cref->location);
}
break;
targs,
last_srf,
fn,
+ false,
fn->location);
}
case EXPR_KIND_RETURNING:
case EXPR_KIND_VALUES:
case EXPR_KIND_VALUES_SINGLE:
+ case EXPR_KIND_CALL:
/* okay */
break;
case EXPR_KIND_CHECK_CONSTRAINT:
return "WHEN";
case EXPR_KIND_PARTITION_EXPRESSION:
return "PARTITION BY";
+ case EXPR_KIND_CALL:
+ return "CALL";
/*
* There is intentionally no default: case here, so that the
*/
Node *
ParseFuncOrColumn(ParseState *pstate, List *funcname, List *fargs,
- Node *last_srf, FuncCall *fn, int location)
+ Node *last_srf, FuncCall *fn, bool proc_call, int location)
{
bool is_column = (fn == NULL);
List *agg_order = (fn ? fn->agg_order : NIL);
actual_arg_types[0], rettype, -1,
COERCION_EXPLICIT, COERCE_EXPLICIT_CALL, location);
}
- else if (fdresult == FUNCDETAIL_NORMAL)
+ else if (fdresult == FUNCDETAIL_NORMAL || fdresult == FUNCDETAIL_PROCEDURE)
{
/*
* Normal function found; was there anything indicating it must be an
errmsg("OVER specified, but %s is not a window function nor an aggregate function",
NameListToString(funcname)),
parser_errposition(pstate, location)));
+
+ if (fdresult == FUNCDETAIL_NORMAL && proc_call)
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_FUNCTION),
+ errmsg("%s is not a procedure",
+ func_signature_string(funcname, nargs,
+ argnames,
+ actual_arg_types)),
+ errhint("To call a function, use SELECT."),
+ parser_errposition(pstate, location)));
+
+ if (fdresult == FUNCDETAIL_PROCEDURE && !proc_call)
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_FUNCTION),
+ errmsg("%s is a procedure",
+ func_signature_string(funcname, nargs,
+ argnames,
+ actual_arg_types)),
+ errhint("To call a procedure, use CALL."),
+ parser_errposition(pstate, location)));
}
else if (fdresult == FUNCDETAIL_AGGREGATE)
{
check_srf_call_placement(pstate, last_srf, location);
/* build the appropriate output structure */
- if (fdresult == FUNCDETAIL_NORMAL)
+ if (fdresult == FUNCDETAIL_NORMAL || fdresult == FUNCDETAIL_PROCEDURE)
{
FuncExpr *funcexpr = makeNode(FuncExpr);
result = FUNCDETAIL_AGGREGATE;
else if (pform->proiswindow)
result = FUNCDETAIL_WINDOWFUNC;
+ else if (pform->prorettype == InvalidOid)
+ result = FUNCDETAIL_PROCEDURE;
else
result = FUNCDETAIL_NORMAL;
ReleaseSysCache(ftup);
/*
* LookupFuncWithArgs
- * Like LookupFuncName, but the argument types are specified by a
- * ObjectWithArgs node.
+ *
+ * Like LookupFuncName, but the argument types are specified by a
+ * ObjectWithArgs node. Also, this function can check whether the result is a
+ * function, procedure, or aggregate, based on the objtype argument. Pass
+ * OBJECT_ROUTINE to accept any of them.
+ *
+ * For historical reasons, we also accept aggregates when looking for a
+ * function.
*/
Oid
-LookupFuncWithArgs(ObjectWithArgs *func, bool noError)
+LookupFuncWithArgs(ObjectType objtype, ObjectWithArgs *func, bool noError)
{
Oid argoids[FUNC_MAX_ARGS];
int argcount;
int i;
ListCell *args_item;
+ Oid oid;
+
+ Assert(objtype == OBJECT_AGGREGATE ||
+ objtype == OBJECT_FUNCTION ||
+ objtype == OBJECT_PROCEDURE ||
+ objtype == OBJECT_ROUTINE);
argcount = list_length(func->objargs);
if (argcount > FUNC_MAX_ARGS)
args_item = lnext(args_item);
}
- return LookupFuncName(func->objname, func->args_unspecified ? -1 : argcount, argoids, noError);
-}
-
-/*
- * LookupAggWithArgs
- * Find an aggregate function from a given ObjectWithArgs node.
- *
- * This is almost like LookupFuncWithArgs, but the error messages refer
- * to aggregates rather than plain functions, and we verify that the found
- * function really is an aggregate.
- */
-Oid
-LookupAggWithArgs(ObjectWithArgs *agg, bool noError)
-{
- Oid argoids[FUNC_MAX_ARGS];
- int argcount;
- int i;
- ListCell *lc;
- Oid oid;
- HeapTuple ftup;
- Form_pg_proc pform;
-
- argcount = list_length(agg->objargs);
- if (argcount > FUNC_MAX_ARGS)
- ereport(ERROR,
- (errcode(ERRCODE_TOO_MANY_ARGUMENTS),
- errmsg_plural("functions cannot have more than %d argument",
- "functions cannot have more than %d arguments",
- FUNC_MAX_ARGS,
- FUNC_MAX_ARGS)));
+ /*
+ * When looking for a function or routine, we pass noError through to
+ * LookupFuncName and let it make any error messages. Otherwise, we make
+ * our own errors for the aggregate and procedure cases.
+ */
+ oid = LookupFuncName(func->objname, func->args_unspecified ? -1 : argcount, argoids,
+ (objtype == OBJECT_FUNCTION || objtype == OBJECT_ROUTINE) ? noError : true);
- i = 0;
- foreach(lc, agg->objargs)
+ if (objtype == OBJECT_FUNCTION)
{
- TypeName *t = (TypeName *) lfirst(lc);
-
- argoids[i] = LookupTypeNameOid(NULL, t, noError);
- i++;
+ /* Make sure it's a function, not a procedure */
+ if (oid && get_func_rettype(oid) == InvalidOid)
+ {
+ if (noError)
+ return InvalidOid;
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("%s is not a function",
+ func_signature_string(func->objname, argcount,
+ NIL, argoids))));
+ }
}
-
- oid = LookupFuncName(agg->objname, argcount, argoids, true);
-
- if (!OidIsValid(oid))
+ else if (objtype == OBJECT_PROCEDURE)
{
- if (noError)
- return InvalidOid;
- if (argcount == 0)
- ereport(ERROR,
- (errcode(ERRCODE_UNDEFINED_FUNCTION),
- errmsg("aggregate %s(*) does not exist",
- NameListToString(agg->objname))));
- else
+ if (!OidIsValid(oid))
+ {
+ if (noError)
+ return InvalidOid;
+ else if (func->args_unspecified)
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_FUNCTION),
+ errmsg("could not find a procedure named \"%s\"",
+ NameListToString(func->objname))));
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_FUNCTION),
+ errmsg("procedure %s does not exist",
+ func_signature_string(func->objname, argcount,
+ NIL, argoids))));
+ }
+
+ /* Make sure it's a procedure */
+ if (get_func_rettype(oid) != InvalidOid)
+ {
+ if (noError)
+ return InvalidOid;
ereport(ERROR,
- (errcode(ERRCODE_UNDEFINED_FUNCTION),
- errmsg("aggregate %s does not exist",
- func_signature_string(agg->objname, argcount,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("%s is not a procedure",
+ func_signature_string(func->objname, argcount,
NIL, argoids))));
+ }
}
-
- /* Make sure it's an aggregate */
- ftup = SearchSysCache1(PROCOID, ObjectIdGetDatum(oid));
- if (!HeapTupleIsValid(ftup)) /* should not happen */
- elog(ERROR, "cache lookup failed for function %u", oid);
- pform = (Form_pg_proc) GETSTRUCT(ftup);
-
- if (!pform->proisagg)
+ else if (objtype == OBJECT_AGGREGATE)
{
- ReleaseSysCache(ftup);
- if (noError)
- return InvalidOid;
- /* we do not use the (*) notation for functions... */
- ereport(ERROR,
- (errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("function %s is not an aggregate",
- func_signature_string(agg->objname, argcount,
- NIL, argoids))));
- }
+ if (!OidIsValid(oid))
+ {
+ if (noError)
+ return InvalidOid;
+ else if (func->args_unspecified)
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_FUNCTION),
+ errmsg("could not find a aggregate named \"%s\"",
+ NameListToString(func->objname))));
+ else if (argcount == 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_FUNCTION),
+ errmsg("aggregate %s(*) does not exist",
+ NameListToString(func->objname))));
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_FUNCTION),
+ errmsg("aggregate %s does not exist",
+ func_signature_string(func->objname, argcount,
+ NIL, argoids))));
+ }
- ReleaseSysCache(ftup);
+ /* Make sure it's an aggregate */
+ if (!get_func_isagg(oid))
+ {
+ if (noError)
+ return InvalidOid;
+ /* we do not use the (*) notation for functions... */
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("function %s is not an aggregate",
+ func_signature_string(func->objname, argcount,
+ NIL, argoids))));
+ }
+ }
return oid;
}
-
/*
* check_srf_call_placement
* Verify that a set-returning function is called in a valid place,
case EXPR_KIND_PARTITION_EXPRESSION:
err = _("set-returning functions are not allowed in partition key expressions");
break;
+ case EXPR_KIND_CALL:
+ err = _("set-returning functions are not allowed in CALL arguments");
+ break;
/*
* There is intentionally no default: case here, so that the
}
break;
+ case T_CallStmt:
+ ExecuteCallStmt(pstate, castNode(CallStmt, parsetree));
+ break;
+
case T_ClusterStmt:
/* we choose to allow this during "read only" transactions */
PreventCommandDuringRecovery("CLUSTER");
case OBJECT_POLICY:
tag = "ALTER POLICY";
break;
+ case OBJECT_PROCEDURE:
+ tag = "ALTER PROCEDURE";
+ break;
case OBJECT_ROLE:
tag = "ALTER ROLE";
break;
+ case OBJECT_ROUTINE:
+ tag = "ALTER ROUTINE";
+ break;
case OBJECT_RULE:
tag = "ALTER RULE";
break;
case OBJECT_FUNCTION:
tag = "DROP FUNCTION";
break;
+ case OBJECT_PROCEDURE:
+ tag = "DROP PROCEDURE";
+ break;
+ case OBJECT_ROUTINE:
+ tag = "DROP ROUTINE";
+ break;
case OBJECT_AGGREGATE:
tag = "DROP AGGREGATE";
break;
break;
case T_AlterFunctionStmt:
- tag = "ALTER FUNCTION";
+ switch (((AlterFunctionStmt *) parsetree)->objtype)
+ {
+ case OBJECT_FUNCTION:
+ tag = "ALTER FUNCTION";
+ break;
+ case OBJECT_PROCEDURE:
+ tag = "ALTER PROCEDURE";
+ break;
+ case OBJECT_ROUTINE:
+ tag = "ALTER ROUTINE";
+ break;
+ default:
+ tag = "???";
+ }
break;
case T_GrantStmt:
break;
case T_CreateFunctionStmt:
- tag = "CREATE FUNCTION";
+ if (((CreateFunctionStmt *) parsetree)->is_procedure)
+ tag = "CREATE PROCEDURE";
+ else
+ tag = "CREATE FUNCTION";
break;
case T_IndexStmt:
tag = "LOAD";
break;
+ case T_CallStmt:
+ tag = "CALL";
+ break;
+
case T_ClusterStmt:
tag = "CLUSTER";
break;
lev = LOGSTMT_ALL;
break;
+ case T_CallStmt:
+ lev = LOGSTMT_ALL;
+ break;
+
case T_ClusterStmt:
lev = LOGSTMT_DDL;
break;
if (!HeapTupleIsValid(proctup))
PG_RETURN_NULL();
+ if (((Form_pg_proc) GETSTRUCT(proctup))->prorettype == InvalidOid)
+ {
+ ReleaseSysCache(proctup);
+ PG_RETURN_NULL();
+ }
+
initStringInfo(&buf);
print_function_rettype(&buf, proctup);
return result;
}
+/*
+ * get_func_isagg
+ * Given procedure id, return the function's proisagg field.
+ */
+bool
+get_func_isagg(Oid funcid)
+{
+ HeapTuple tp;
+ bool result;
+
+ tp = SearchSysCache1(PROCOID, ObjectIdGetDatum(funcid));
+ if (!HeapTupleIsValid(tp))
+ elog(ERROR, "cache lookup failed for function %u", funcid);
+
+ result = ((Form_pg_proc) GETSTRUCT(tp))->proisagg;
+ ReleaseSysCache(tp);
+ return result;
+}
+
/*
* get_func_leakproof
* Given procedure id, return the function's leakproof field.
* name: the object name, in the form to use in the commands (already quoted)
* subname: the sub-object name, if any (already quoted); NULL if none
* type: the object type (as seen in GRANT command: must be one of
- * TABLE, SEQUENCE, FUNCTION, LANGUAGE, SCHEMA, DATABASE, TABLESPACE,
+ * TABLE, SEQUENCE, FUNCTION, PROCEDURE, LANGUAGE, SCHEMA, DATABASE, TABLESPACE,
* FOREIGN DATA WRAPPER, SERVER, or LARGE OBJECT)
* acls: the ACL string fetched from the database
* racls: the ACL string of any initial-but-now-revoked privileges
else if (strcmp(type, "FUNCTION") == 0 ||
strcmp(type, "FUNCTIONS") == 0)
CONVERT_PRIV('X', "EXECUTE");
+ else if (strcmp(type, "PROCEDURE") == 0 ||
+ strcmp(type, "PROCEDURES") == 0)
+ CONVERT_PRIV('X', "EXECUTE");
else if (strcmp(type, "LANGUAGE") == 0)
CONVERT_PRIV('U', "USAGE");
else if (strcmp(type, "SCHEMA") == 0 ||
if (ropt->indexNames.head != NULL && (!(simple_string_list_member(&ropt->indexNames, te->tag))))
return 0;
}
- else if (strcmp(te->desc, "FUNCTION") == 0)
+ else if (strcmp(te->desc, "FUNCTION") == 0 ||
+ strcmp(te->desc, "PROCEDURE") == 0)
{
if (!ropt->selFunction)
return 0;
strcmp(type, "FUNCTION") == 0 ||
strcmp(type, "OPERATOR") == 0 ||
strcmp(type, "OPERATOR CLASS") == 0 ||
- strcmp(type, "OPERATOR FAMILY") == 0)
+ strcmp(type, "OPERATOR FAMILY") == 0 ||
+ strcmp(type, "PROCEDURE") == 0)
{
/* Chop "DROP " off the front and make a modifiable copy */
char *first = pg_strdup(te->dropStmt + 5);
strcmp(te->desc, "OPERATOR") == 0 ||
strcmp(te->desc, "OPERATOR CLASS") == 0 ||
strcmp(te->desc, "OPERATOR FAMILY") == 0 ||
+ strcmp(te->desc, "PROCEDURE") == 0 ||
strcmp(te->desc, "PROCEDURAL LANGUAGE") == 0 ||
strcmp(te->desc, "SCHEMA") == 0 ||
strcmp(te->desc, "EVENT TRIGGER") == 0 ||
char *funcargs;
char *funciargs;
char *funcresult;
+ bool is_procedure;
char *proallargtypes;
char *proargmodes;
char *proargnames;
char **argnames = NULL;
char **configitems = NULL;
int nconfigitems = 0;
+ const char *keyword;
int i;
/* Skip if not to be dumped */
{
funcargs = PQgetvalue(res, 0, PQfnumber(res, "funcargs"));
funciargs = PQgetvalue(res, 0, PQfnumber(res, "funciargs"));
- funcresult = PQgetvalue(res, 0, PQfnumber(res, "funcresult"));
+ is_procedure = PQgetisnull(res, 0, PQfnumber(res, "funcresult"));
+ if (is_procedure)
+ funcresult = NULL;
+ else
+ funcresult = PQgetvalue(res, 0, PQfnumber(res, "funcresult"));
proallargtypes = proargmodes = proargnames = NULL;
}
else
proargmodes = PQgetvalue(res, 0, PQfnumber(res, "proargmodes"));
proargnames = PQgetvalue(res, 0, PQfnumber(res, "proargnames"));
funcargs = funciargs = funcresult = NULL;
+ is_procedure = false;
}
if (PQfnumber(res, "protrftypes") != -1)
protrftypes = PQgetvalue(res, 0, PQfnumber(res, "protrftypes"));
funcsig_tag = format_function_signature(fout, finfo, false);
+ keyword = is_procedure ? "PROCEDURE" : "FUNCTION";
+
/*
* DROP must be fully qualified in case same name appears in pg_catalog
*/
- appendPQExpBuffer(delqry, "DROP FUNCTION %s.%s;\n",
+ appendPQExpBuffer(delqry, "DROP %s %s.%s;\n",
+ keyword,
fmtId(finfo->dobj.namespace->dobj.name),
funcsig);
- appendPQExpBuffer(q, "CREATE FUNCTION %s ", funcfullsig ? funcfullsig :
+ appendPQExpBuffer(q, "CREATE %s %s",
+ keyword,
+ funcfullsig ? funcfullsig :
funcsig);
- if (funcresult)
- appendPQExpBuffer(q, "RETURNS %s", funcresult);
+ if (is_procedure)
+ ;
+ else if (funcresult)
+ appendPQExpBuffer(q, " RETURNS %s", funcresult);
else
{
rettypename = getFormattedTypeName(fout, finfo->prorettype,
zeroAsOpaque);
- appendPQExpBuffer(q, "RETURNS %s%s",
+ appendPQExpBuffer(q, " RETURNS %s%s",
(proretset[0] == 't') ? "SETOF " : "",
rettypename);
free(rettypename);
appendPQExpBuffer(q, "\n %s;\n", asPart->data);
- appendPQExpBuffer(labelq, "FUNCTION %s", funcsig);
+ appendPQExpBuffer(labelq, "%s %s", keyword, funcsig);
if (dopt->binary_upgrade)
binary_upgrade_extension_member(q, &finfo->dobj, labelq->data);
finfo->dobj.namespace->dobj.name,
NULL,
finfo->rolname, false,
- "FUNCTION", SECTION_PRE_DATA,
+ keyword, SECTION_PRE_DATA,
q->data, delqry->data, NULL,
NULL, 0,
NULL, NULL);
finfo->dobj.catId, 0, finfo->dobj.dumpId);
if (finfo->dobj.dump & DUMP_COMPONENT_ACL)
- dumpACL(fout, finfo->dobj.catId, finfo->dobj.dumpId, "FUNCTION",
+ dumpACL(fout, finfo->dobj.catId, finfo->dobj.dumpId, keyword,
funcsig, NULL, funcsig_tag,
finfo->dobj.namespace->dobj.name,
finfo->rolname, finfo->proacl, finfo->rproacl,
section_data => 1,
section_post_data => 1, }, },
+ 'CREATE PROCEDURE dump_test.ptest1' => {
+ all_runs => 1,
+ create_order => 41,
+ create_sql => 'CREATE PROCEDURE dump_test.ptest1(a int)
+ LANGUAGE SQL AS $$ INSERT INTO dump_test.test_table (col1) VALUES (a) $$;',
+ regexp => qr/^
+ \QCREATE PROCEDURE ptest1(a integer)\E
+ \n\s+\QLANGUAGE sql\E
+ \n\s+AS\ \$\$\Q INSERT INTO dump_test.test_table (col1) VALUES (a) \E\$\$;
+ /xm,
+ like => {
+ binary_upgrade => 1,
+ clean => 1,
+ clean_if_exists => 1,
+ createdb => 1,
+ defaults => 1,
+ exclude_test_table => 1,
+ exclude_test_table_data => 1,
+ no_blobs => 1,
+ no_privs => 1,
+ no_owner => 1,
+ only_dump_test_schema => 1,
+ pg_dumpall_dbprivs => 1,
+ schema_only => 1,
+ section_pre_data => 1,
+ test_schema_plus_blobs => 1,
+ with_oids => 1, },
+ unlike => {
+ column_inserts => 1,
+ data_only => 1,
+ exclude_dump_test_schema => 1,
+ only_dump_test_table => 1,
+ pg_dumpall_globals => 1,
+ pg_dumpall_globals_clean => 1,
+ role => 1,
+ section_data => 1,
+ section_post_data => 1, }, },
+
'CREATE TYPE dump_test.int42 populated' => {
all_runs => 1,
create_order => 42,
" CASE\n"
" WHEN p.proisagg THEN '%s'\n"
" WHEN p.proiswindow THEN '%s'\n"
+ " WHEN p.prorettype = 0 THEN '%s'\n"
" WHEN p.prorettype = 'pg_catalog.trigger'::pg_catalog.regtype THEN '%s'\n"
" ELSE '%s'\n"
" END as \"%s\"",
/* translator: "agg" is short for "aggregate" */
gettext_noop("agg"),
gettext_noop("window"),
+ gettext_noop("proc"),
gettext_noop("trigger"),
- gettext_noop("normal"),
+ gettext_noop("func"),
gettext_noop("Type"));
else if (pset.sversion >= 80100)
appendPQExpBuffer(&buf,
/* translator: "agg" is short for "aggregate" */
gettext_noop("agg"),
gettext_noop("trigger"),
- gettext_noop("normal"),
+ gettext_noop("func"),
gettext_noop("Type"));
else
appendPQExpBuffer(&buf,
/* translator: "agg" is short for "aggregate" */
gettext_noop("agg"),
gettext_noop("trigger"),
- gettext_noop("normal"),
+ gettext_noop("func"),
gettext_noop("Type"));
if (verbose)
/* catname */
"pg_catalog.pg_proc p",
/* selcondition */
- NULL,
+ "p.prorettype <> 0",
/* viscondition */
"pg_catalog.pg_function_is_visible(p.oid)",
/* namespace */
NULL
};
+static const SchemaQuery Query_for_list_of_procedures = {
+ /* catname */
+ "pg_catalog.pg_proc p",
+ /* selcondition */
+ "p.prorettype = 0",
+ /* viscondition */
+ "pg_catalog.pg_function_is_visible(p.oid)",
+ /* namespace */
+ "p.pronamespace",
+ /* result */
+ "pg_catalog.quote_ident(p.proname)",
+ /* qualresult */
+ NULL
+};
+
+static const SchemaQuery Query_for_list_of_routines = {
+ /* catname */
+ "pg_catalog.pg_proc p",
+ /* selcondition */
+ NULL,
+ /* viscondition */
+ "pg_catalog.pg_function_is_visible(p.oid)",
+ /* namespace */
+ "p.pronamespace",
+ /* result */
+ "pg_catalog.quote_ident(p.proname)",
+ /* qualresult */
+ NULL
+};
+
static const SchemaQuery Query_for_list_of_sequences = {
/* catname */
"pg_catalog.pg_class c",
{"OWNED", NULL, NULL, THING_NO_CREATE | THING_NO_ALTER}, /* for DROP OWNED BY ... */
{"PARSER", Query_for_list_of_ts_parsers, NULL, THING_NO_SHOW},
{"POLICY", NULL, NULL},
+ {"PROCEDURE", NULL, &Query_for_list_of_procedures},
{"PUBLICATION", Query_for_list_of_publications},
{"ROLE", Query_for_list_of_roles},
+ {"ROUTINE", NULL, &Query_for_list_of_routines, THING_NO_CREATE},
{"RULE", "SELECT pg_catalog.quote_ident(rulename) FROM pg_catalog.pg_rules WHERE substring(pg_catalog.quote_ident(rulename),1,%d)='%s'"},
{"SCHEMA", Query_for_list_of_schemas},
{"SEQUENCE", NULL, &Query_for_list_of_sequences},
/* Known command-starting keywords. */
static const char *const sql_commands[] = {
- "ABORT", "ALTER", "ANALYZE", "BEGIN", "CHECKPOINT", "CLOSE", "CLUSTER",
+ "ABORT", "ALTER", "ANALYZE", "BEGIN", "CALL", "CHECKPOINT", "CLOSE", "CLUSTER",
"COMMENT", "COMMIT", "COPY", "CREATE", "DEALLOCATE", "DECLARE",
"DELETE FROM", "DISCARD", "DO", "DROP", "END", "EXECUTE", "EXPLAIN",
"FETCH", "GRANT", "IMPORT", "INSERT", "LISTEN", "LOAD", "LOCK",
/* ALTER TABLE,INDEX,MATERIALIZED VIEW ALL IN TABLESPACE xxx OWNED BY xxx */
else if (TailMatches7("ALL", "IN", "TABLESPACE", MatchAny, "OWNED", "BY", MatchAny))
COMPLETE_WITH_CONST("SET TABLESPACE");
- /* ALTER AGGREGATE,FUNCTION <name> */
- else if (Matches3("ALTER", "AGGREGATE|FUNCTION", MatchAny))
+ /* ALTER AGGREGATE,FUNCTION,PROCEDURE,ROUTINE <name> */
+ else if (Matches3("ALTER", "AGGREGATE|FUNCTION|PROCEDURE|ROUTINE", MatchAny))
COMPLETE_WITH_CONST("(");
- /* ALTER AGGREGATE,FUNCTION <name> (...) */
- else if (Matches4("ALTER", "AGGREGATE|FUNCTION", MatchAny, MatchAny))
+ /* ALTER AGGREGATE,FUNCTION,PROCEDURE,ROUTINE <name> (...) */
+ else if (Matches4("ALTER", "AGGREGATE|FUNCTION|PROCEDURE|ROUTINE", MatchAny, MatchAny))
{
if (ends_with(prev_wd, ')'))
COMPLETE_WITH_LIST3("OWNER TO", "RENAME TO", "SET SCHEMA");
/* ROLLBACK */
else if (Matches1("ROLLBACK"))
COMPLETE_WITH_LIST4("WORK", "TRANSACTION", "TO SAVEPOINT", "PREPARED");
+/* CALL */
+ else if (Matches1("CALL"))
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_procedures, NULL);
+ else if (Matches2("CALL", MatchAny))
+ COMPLETE_WITH_CONST("(");
/* CLUSTER */
else if (Matches1("CLUSTER"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_tm, "UNION SELECT 'VERBOSE'");
"SERVER", "INDEX", "LANGUAGE", "POLICY", "PUBLICATION", "RULE",
"SCHEMA", "SEQUENCE", "STATISTICS", "SUBSCRIPTION",
"TABLE", "TYPE", "VIEW", "MATERIALIZED VIEW", "COLUMN", "AGGREGATE", "FUNCTION",
+ "PROCEDURE", "ROUTINE",
"OPERATOR", "TRIGGER", "CONSTRAINT", "DOMAIN", "LARGE OBJECT",
"TABLESPACE", "TEXT SEARCH", "ROLE", NULL};
"COLLATION|CONVERSION|DOMAIN|EXTENSION|LANGUAGE|PUBLICATION|SCHEMA|SEQUENCE|SERVER|SUBSCRIPTION|STATISTICS|TABLE|TYPE|VIEW",
MatchAny) ||
Matches4("DROP", "ACCESS", "METHOD", MatchAny) ||
- (Matches4("DROP", "AGGREGATE|FUNCTION", MatchAny, MatchAny) &&
+ (Matches4("DROP", "AGGREGATE|FUNCTION|PROCEDURE|ROUTINE", MatchAny, MatchAny) &&
ends_with(prev_wd, ')')) ||
Matches4("DROP", "EVENT", "TRIGGER", MatchAny) ||
Matches5("DROP", "FOREIGN", "DATA", "WRAPPER", MatchAny) ||
COMPLETE_WITH_LIST2("CASCADE", "RESTRICT");
/* help completing some of the variants */
- else if (Matches3("DROP", "AGGREGATE|FUNCTION", MatchAny))
+ else if (Matches3("DROP", "AGGREGATE|FUNCTION|PROCEDURE|ROUTINE", MatchAny))
COMPLETE_WITH_CONST("(");
- else if (Matches4("DROP", "AGGREGATE|FUNCTION", MatchAny, "("))
+ else if (Matches4("DROP", "AGGREGATE|FUNCTION|PROCEDURE|ROUTINE", MatchAny, "("))
COMPLETE_WITH_FUNCTION_ARG(prev2_wd);
else if (Matches2("DROP", "FOREIGN"))
COMPLETE_WITH_LIST2("DATA WRAPPER", "TABLE");
* objects supported.
*/
if (HeadMatches3("ALTER", "DEFAULT", "PRIVILEGES"))
- COMPLETE_WITH_LIST5("TABLES", "SEQUENCES", "FUNCTIONS", "TYPES", "SCHEMAS");
+ COMPLETE_WITH_LIST7("TABLES", "SEQUENCES", "FUNCTIONS", "PROCEDURES", "ROUTINES", "TYPES", "SCHEMAS");
else
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_tsvmf,
" UNION SELECT 'ALL FUNCTIONS IN SCHEMA'"
+ " UNION SELECT 'ALL PROCEDURES IN SCHEMA'"
+ " UNION SELECT 'ALL ROUTINES IN SCHEMA'"
" UNION SELECT 'ALL SEQUENCES IN SCHEMA'"
" UNION SELECT 'ALL TABLES IN SCHEMA'"
" UNION SELECT 'DATABASE'"
" UNION SELECT 'FUNCTION'"
" UNION SELECT 'LANGUAGE'"
" UNION SELECT 'LARGE OBJECT'"
+ " UNION SELECT 'PROCEDURE'"
+ " UNION SELECT 'ROUTINE'"
" UNION SELECT 'SCHEMA'"
" UNION SELECT 'SEQUENCE'"
" UNION SELECT 'TABLE'"
" UNION SELECT 'TYPE'");
}
else if (TailMatches4("GRANT|REVOKE", MatchAny, "ON", "ALL"))
- COMPLETE_WITH_LIST3("FUNCTIONS IN SCHEMA", "SEQUENCES IN SCHEMA",
+ COMPLETE_WITH_LIST5("FUNCTIONS IN SCHEMA",
+ "PROCEDURES IN SCHEMA",
+ "ROUTINES IN SCHEMA",
+ "SEQUENCES IN SCHEMA",
"TABLES IN SCHEMA");
else if (TailMatches4("GRANT|REVOKE", MatchAny, "ON", "FOREIGN"))
COMPLETE_WITH_LIST2("DATA WRAPPER", "SERVER");
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_functions, NULL);
else if (TailMatches1("LANGUAGE"))
COMPLETE_WITH_QUERY(Query_for_list_of_languages);
+ else if (TailMatches1("PROCEDURE"))
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_procedures, NULL);
+ else if (TailMatches1("ROUTINE"))
+ COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_routines, NULL);
else if (TailMatches1("SCHEMA"))
COMPLETE_WITH_QUERY(Query_for_list_of_schemas);
else if (TailMatches1("SEQUENCE"))
static const char *const list_SECURITY_LABEL[] =
{"TABLE", "COLUMN", "AGGREGATE", "DATABASE", "DOMAIN",
"EVENT TRIGGER", "FOREIGN TABLE", "FUNCTION", "LARGE OBJECT",
- "MATERIALIZED VIEW", "LANGUAGE", "PUBLICATION", "ROLE", "SCHEMA",
+ "MATERIALIZED VIEW", "LANGUAGE", "PUBLICATION", "PROCEDURE", "ROLE", "ROUTINE", "SCHEMA",
"SEQUENCE", "SUBSCRIPTION", "TABLESPACE", "TYPE", "VIEW", NULL};
COMPLETE_WITH_LIST(list_SECURITY_LABEL);
/* Complete SET <var> with "TO" */
else if (Matches2("SET", MatchAny))
COMPLETE_WITH_CONST("TO");
- /* Complete ALTER DATABASE|FUNCTION|ROLE|USER ... SET <name> */
- else if (HeadMatches2("ALTER", "DATABASE|FUNCTION|ROLE|USER") &&
+ /* Complete ALTER DATABASE|FUNCTION||PROCEDURE|ROLE|ROUTINE|USER ... SET <name> */
+ else if (HeadMatches2("ALTER", "DATABASE|FUNCTION|PROCEDURE|ROLE|ROUTINE|USER") &&
TailMatches2("SET", MatchAny))
COMPLETE_WITH_LIST2("FROM CURRENT", "TO");
/* Suggest possible variable values */
*/
/* yyyymmddN */
-#define CATALOG_VERSION_NO 201711171
+#define CATALOG_VERSION_NO 201711301
#endif
extern void IsThereFunctionInNamespace(const char *proname, int pronargs,
oidvector *proargtypes, Oid nspOid);
extern void ExecuteDoStmt(DoStmt *stmt);
+extern void ExecuteCallStmt(ParseState *pstate, CallStmt *stmt);
extern Oid get_cast_oid(Oid sourcetypeid, Oid targettypeid, bool missing_ok);
extern Oid get_transform_oid(Oid type_id, Oid lang_id, bool missing_ok);
extern void interpret_function_parameter_list(ParseState *pstate,
List *parameters,
Oid languageOid,
- bool is_aggregate,
+ ObjectType objtype,
oidvector **parameterTypes,
ArrayType **allParameterTypes,
ArrayType **parameterModes,
T_DropSubscriptionStmt,
T_CreateStatsStmt,
T_AlterCollationStmt,
+ T_CallStmt,
/*
* TAGS FOR PARSE TREE NODES (parsenodes.h)
OBJECT_OPERATOR,
OBJECT_OPFAMILY,
OBJECT_POLICY,
+ OBJECT_PROCEDURE,
OBJECT_PUBLICATION,
OBJECT_PUBLICATION_REL,
OBJECT_ROLE,
+ OBJECT_ROUTINE,
OBJECT_RULE,
OBJECT_SCHEMA,
OBJECT_SEQUENCE,
ACL_OBJECT_LANGUAGE, /* procedural language */
ACL_OBJECT_LARGEOBJECT, /* largeobject */
ACL_OBJECT_NAMESPACE, /* namespace */
+ ACL_OBJECT_PROCEDURE, /* procedure */
+ ACL_OBJECT_ROUTINE, /* routine */
ACL_OBJECT_TABLESPACE, /* tablespace */
ACL_OBJECT_TYPE /* type */
} GrantObjectType;
List *funcname; /* qualified name of function to create */
List *parameters; /* a list of FunctionParameter */
TypeName *returnType; /* the return type */
+ bool is_procedure;
List *options; /* a list of DefElem */
List *withClause; /* a list of DefElem */
} CreateFunctionStmt;
typedef struct AlterFunctionStmt
{
NodeTag type;
+ ObjectType objtype;
ObjectWithArgs *func; /* name and args of function */
List *actions; /* list of DefElem */
} AlterFunctionStmt;
bool langIsTrusted; /* trusted property of the language */
} InlineCodeBlock;
+/* ----------------------
+ * CALL statement
+ * ----------------------
+ */
+typedef struct CallStmt
+{
+ NodeTag type;
+ FuncCall *funccall;
+} CallStmt;
+
/* ----------------------
* Alter Object Rename Statement
* ----------------------
PG_KEYWORD("both", BOTH, RESERVED_KEYWORD)
PG_KEYWORD("by", BY, UNRESERVED_KEYWORD)
PG_KEYWORD("cache", CACHE, UNRESERVED_KEYWORD)
+PG_KEYWORD("call", CALL, UNRESERVED_KEYWORD)
PG_KEYWORD("called", CALLED, UNRESERVED_KEYWORD)
PG_KEYWORD("cascade", CASCADE, UNRESERVED_KEYWORD)
PG_KEYWORD("cascaded", CASCADED, UNRESERVED_KEYWORD)
PG_KEYWORD("privileges", PRIVILEGES, UNRESERVED_KEYWORD)
PG_KEYWORD("procedural", PROCEDURAL, UNRESERVED_KEYWORD)
PG_KEYWORD("procedure", PROCEDURE, UNRESERVED_KEYWORD)
+PG_KEYWORD("procedures", PROCEDURES, UNRESERVED_KEYWORD)
PG_KEYWORD("program", PROGRAM, UNRESERVED_KEYWORD)
PG_KEYWORD("publication", PUBLICATION, UNRESERVED_KEYWORD)
PG_KEYWORD("quote", QUOTE, UNRESERVED_KEYWORD)
PG_KEYWORD("role", ROLE, UNRESERVED_KEYWORD)
PG_KEYWORD("rollback", ROLLBACK, UNRESERVED_KEYWORD)
PG_KEYWORD("rollup", ROLLUP, UNRESERVED_KEYWORD)
+PG_KEYWORD("routine", ROUTINE, UNRESERVED_KEYWORD)
+PG_KEYWORD("routines", ROUTINES, UNRESERVED_KEYWORD)
PG_KEYWORD("row", ROW, COL_NAME_KEYWORD)
PG_KEYWORD("rows", ROWS, UNRESERVED_KEYWORD)
PG_KEYWORD("rule", RULE, UNRESERVED_KEYWORD)
FUNCDETAIL_NOTFOUND, /* no matching function */
FUNCDETAIL_MULTIPLE, /* too many matching functions */
FUNCDETAIL_NORMAL, /* found a matching regular function */
+ FUNCDETAIL_PROCEDURE, /* found a matching procedure */
FUNCDETAIL_AGGREGATE, /* found a matching aggregate function */
FUNCDETAIL_WINDOWFUNC, /* found a matching window function */
FUNCDETAIL_COERCION /* it's a type coercion request */
extern Node *ParseFuncOrColumn(ParseState *pstate, List *funcname, List *fargs,
- Node *last_srf, FuncCall *fn, int location);
+ Node *last_srf, FuncCall *fn, bool proc_call,
+ int location);
extern FuncDetailCode func_get_detail(List *funcname,
List *fargs, List *fargnames,
extern Oid LookupFuncName(List *funcname, int nargs, const Oid *argtypes,
bool noError);
-extern Oid LookupFuncWithArgs(ObjectWithArgs *func,
+extern Oid LookupFuncWithArgs(ObjectType objtype, ObjectWithArgs *func,
bool noError);
-extern Oid LookupAggWithArgs(ObjectWithArgs *agg,
- bool noError);
extern void check_srf_call_placement(ParseState *pstate, Node *last_srf,
int location);
EXPR_KIND_EXECUTE_PARAMETER, /* parameter value in EXECUTE */
EXPR_KIND_TRIGGER_WHEN, /* WHEN condition in CREATE TRIGGER */
EXPR_KIND_POLICY, /* USING or WITH CHECK expr in policy */
- EXPR_KIND_PARTITION_EXPRESSION /* PARTITION BY expression */
+ EXPR_KIND_PARTITION_EXPRESSION, /* PARTITION BY expression */
+ EXPR_KIND_CALL /* CALL argument */
} ParseExprKind;
extern bool func_strict(Oid funcid);
extern char func_volatile(Oid funcid);
extern char func_parallel(Oid funcid);
+extern bool get_func_isagg(Oid funcid);
extern bool get_func_leakproof(Oid funcid);
extern float4 get_func_cost(Oid funcid);
extern float4 get_func_rows(Oid funcid);
/* special embedded SQL tokens */
%token SQL_ALLOCATE SQL_AUTOCOMMIT SQL_BOOL SQL_BREAK
- SQL_CALL SQL_CARDINALITY SQL_CONNECT
+ SQL_CARDINALITY SQL_CONNECT
SQL_COUNT
SQL_DATETIME_INTERVAL_CODE
SQL_DATETIME_INTERVAL_PRECISION SQL_DESCRIBE
$<action>$.command = NULL;
$<action>$.str = mm_strdup("continue");
}
- | SQL_CALL name '(' c_args ')'
+ | CALL name '(' c_args ')'
{
$<action>$.code = W_DO;
$<action>$.command = cat_str(4, $2, mm_strdup("("), $4, mm_strdup(")"));
$<action>$.str = cat2_str(mm_strdup("call"), mm_strdup($<action>$.command));
}
- | SQL_CALL name
+ | CALL name
{
$<action>$.code = W_DO;
$<action>$.command = cat2_str($2, mm_strdup("()"));
;
ECPGKeywords_vanames: SQL_BREAK { $$ = mm_strdup("break"); }
- | SQL_CALL { $$ = mm_strdup("call"); }
| SQL_CARDINALITY { $$ = mm_strdup("cardinality"); }
| SQL_COUNT { $$ = mm_strdup("count"); }
| SQL_DATETIME_INTERVAL_CODE { $$ = mm_strdup("datetime_interval_code"); }
{"autocommit", SQL_AUTOCOMMIT, 0},
{"bool", SQL_BOOL, 0},
{"break", SQL_BREAK, 0},
- {"call", SQL_CALL, 0},
{"cardinality", SQL_CARDINALITY, 0},
{"connect", SQL_CONNECT, 0},
{"count", SQL_COUNT, 0},
SHLIB_LINK = $(perl_embed_ldflags)
REGRESS_OPTS = --dbname=$(PL_TESTDB) --load-extension=plperl --load-extension=plperlu
-REGRESS = plperl plperl_lc plperl_trigger plperl_shared plperl_elog plperl_util plperl_init plperlu plperl_array
+REGRESS = plperl plperl_lc plperl_trigger plperl_shared plperl_elog plperl_util plperl_init plperlu plperl_array plperl_call
# if Perl can support two interpreters in one backend,
# test plperl-and-plperlu cases
ifneq ($(PERL),)
--- /dev/null
+CREATE PROCEDURE test_proc1()
+LANGUAGE plperl
+AS $$
+undef;
+$$;
+CALL test_proc1();
+CREATE PROCEDURE test_proc2()
+LANGUAGE plperl
+AS $$
+return 5
+$$;
+CALL test_proc2();
+CREATE TABLE test1 (a int);
+CREATE PROCEDURE test_proc3(x int)
+LANGUAGE plperl
+AS $$
+spi_exec_query("INSERT INTO test1 VALUES ($_[0])");
+$$;
+CALL test_proc3(55);
+SELECT * FROM test1;
+ a
+----
+ 55
+(1 row)
+
+DROP PROCEDURE test_proc1;
+DROP PROCEDURE test_proc2;
+DROP PROCEDURE test_proc3;
+DROP TABLE test1;
desc.fn_retistuple = false;
desc.fn_retisset = false;
desc.fn_retisarray = false;
- desc.result_oid = VOIDOID;
+ desc.result_oid = InvalidOid;
desc.nargs = 0;
desc.reference = NULL;
}
retval = (Datum) 0;
}
- else
+ else if (prodesc->result_oid)
{
retval = plperl_sv_to_datum(perlret,
prodesc->result_oid,
* Get the required information for input conversion of the
* return value.
************************************************************/
- if (!is_trigger && !is_event_trigger)
+ if (!is_trigger && !is_event_trigger && procStruct->prorettype)
{
Oid rettype = procStruct->prorettype;
tuplestore_puttuple(current_call_data->tuple_store, tuple);
}
- else
+ else if (prodesc->result_oid)
{
Datum ret[1];
bool isNull[1];
--- /dev/null
+CREATE PROCEDURE test_proc1()
+LANGUAGE plperl
+AS $$
+undef;
+$$;
+
+CALL test_proc1();
+
+
+CREATE PROCEDURE test_proc2()
+LANGUAGE plperl
+AS $$
+return 5
+$$;
+
+CALL test_proc2();
+
+
+CREATE TABLE test1 (a int);
+
+CREATE PROCEDURE test_proc3(x int)
+LANGUAGE plperl
+AS $$
+spi_exec_query("INSERT INTO test1 VALUES ($_[0])");
+$$;
+
+CALL test_proc3(55);
+
+SELECT * FROM test1;
+
+
+DROP PROCEDURE test_proc1;
+DROP PROCEDURE test_proc2;
+DROP PROCEDURE test_proc3;
+
+DROP TABLE test1;
bool isnull;
char *proc_source;
HeapTuple typeTup;
- Form_pg_type typeStruct;
PLpgSQL_variable *var;
PLpgSQL_rec *rec;
int i;
/*
* Lookup the function's return type
*/
- typeTup = SearchSysCache1(TYPEOID, ObjectIdGetDatum(rettypeid));
- if (!HeapTupleIsValid(typeTup))
- elog(ERROR, "cache lookup failed for type %u", rettypeid);
- typeStruct = (Form_pg_type) GETSTRUCT(typeTup);
-
- /* Disallow pseudotype result, except VOID or RECORD */
- /* (note we already replaced polymorphic types) */
- if (typeStruct->typtype == TYPTYPE_PSEUDO)
+ if (rettypeid)
{
- if (rettypeid == VOIDOID ||
- rettypeid == RECORDOID)
- /* okay */ ;
- else if (rettypeid == TRIGGEROID || rettypeid == EVTTRIGGEROID)
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("trigger functions can only be called as triggers")));
- else
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("PL/pgSQL functions cannot return type %s",
- format_type_be(rettypeid))));
- }
+ Form_pg_type typeStruct;
- if (typeStruct->typrelid != InvalidOid ||
- rettypeid == RECORDOID)
- function->fn_retistuple = true;
- else
- {
- function->fn_retbyval = typeStruct->typbyval;
- function->fn_rettyplen = typeStruct->typlen;
+ typeTup = SearchSysCache1(TYPEOID, ObjectIdGetDatum(rettypeid));
+ if (!HeapTupleIsValid(typeTup))
+ elog(ERROR, "cache lookup failed for type %u", rettypeid);
+ typeStruct = (Form_pg_type) GETSTRUCT(typeTup);
- /*
- * install $0 reference, but only for polymorphic return
- * types, and not when the return is specified through an
- * output parameter.
- */
- if (IsPolymorphicType(procStruct->prorettype) &&
- num_out_args == 0)
+ /* Disallow pseudotype result, except VOID or RECORD */
+ /* (note we already replaced polymorphic types) */
+ if (typeStruct->typtype == TYPTYPE_PSEUDO)
{
- (void) plpgsql_build_variable("$0", 0,
- build_datatype(typeTup,
- -1,
- function->fn_input_collation),
- true);
+ if (rettypeid == VOIDOID ||
+ rettypeid == RECORDOID)
+ /* okay */ ;
+ else if (rettypeid == TRIGGEROID || rettypeid == EVTTRIGGEROID)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("trigger functions can only be called as triggers")));
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("PL/pgSQL functions cannot return type %s",
+ format_type_be(rettypeid))));
+ }
+
+ if (typeStruct->typrelid != InvalidOid ||
+ rettypeid == RECORDOID)
+ function->fn_retistuple = true;
+ else
+ {
+ function->fn_retbyval = typeStruct->typbyval;
+ function->fn_rettyplen = typeStruct->typlen;
+
+ /*
+ * install $0 reference, but only for polymorphic return
+ * types, and not when the return is specified through an
+ * output parameter.
+ */
+ if (IsPolymorphicType(procStruct->prorettype) &&
+ num_out_args == 0)
+ {
+ (void) plpgsql_build_variable("$0", 0,
+ build_datatype(typeTup,
+ -1,
+ function->fn_input_collation),
+ true);
+ }
}
+ ReleaseSysCache(typeTup);
}
- ReleaseSysCache(typeTup);
break;
case PLPGSQL_DML_TRIGGER:
estate.err_text = NULL;
estate.err_stmt = (PLpgSQL_stmt *) (func->action);
rc = exec_stmt_block(&estate, func->action);
- if (rc != PLPGSQL_RC_RETURN)
+ if (rc != PLPGSQL_RC_RETURN && func->fn_rettype)
{
estate.err_stmt = NULL;
estate.err_text = NULL;
}
else if (!estate.retisnull)
{
+ if (!func->fn_rettype)
+ {
+ ereport(ERROR,
+ (errmsg("cannot return a value from a procedure")));
+ }
+
if (estate.retistuple)
{
/*
plpython_spi \
plpython_newline \
plpython_void \
+ plpython_call \
plpython_params \
plpython_setof \
plpython_record \
--- /dev/null
+--
+-- Tests for procedures / CALL syntax
+--
+CREATE PROCEDURE test_proc1()
+LANGUAGE plpythonu
+AS $$
+pass
+$$;
+CALL test_proc1();
+-- error: can't return non-None
+CREATE PROCEDURE test_proc2()
+LANGUAGE plpythonu
+AS $$
+return 5
+$$;
+CALL test_proc2();
+ERROR: PL/Python procedure did not return None
+CONTEXT: PL/Python procedure "test_proc2"
+CREATE TABLE test1 (a int);
+CREATE PROCEDURE test_proc3(x int)
+LANGUAGE plpythonu
+AS $$
+plpy.execute("INSERT INTO test1 VALUES (%s)" % x)
+$$;
+CALL test_proc3(55);
+SELECT * FROM test1;
+ a
+----
+ 55
+(1 row)
+
+DROP PROCEDURE test_proc1;
+DROP PROCEDURE test_proc2;
+DROP PROCEDURE test_proc3;
+DROP TABLE test1;
error_context_stack = &plerrcontext;
/*
- * If the function is declared to return void, the Python return value
+ * For a procedure or function declared to return void, the Python return value
* must be None. For void-returning functions, we also treat a None
* return value as a special "void datum" rather than NULL (as is the
* case for non-void-returning functions).
*/
- if (proc->result.typoid == VOIDOID)
+ if (proc->is_procedure)
+ {
+ if (plrv != Py_None)
+ ereport(ERROR,
+ (errcode(ERRCODE_DATATYPE_MISMATCH),
+ errmsg("PL/Python procedure did not return None")));
+ }
+ else if (proc->result.typoid == VOIDOID)
{
if (plrv != Py_None)
ereport(ERROR,
{
PLyExecutionContext *exec_ctx = PLy_current_execution_context();
- if (exec_ctx->curr_proc)
+ if (exec_ctx->curr_proc &&
+ !exec_ctx->curr_proc->is_procedure)
errcontext("while creating return value");
}
PLyExecutionContext *exec_ctx = PLy_current_execution_context();
if (exec_ctx->curr_proc)
- errcontext("PL/Python function \"%s\"",
- PLy_procedure_name(exec_ctx->curr_proc));
+ {
+ if (exec_ctx->curr_proc->is_procedure)
+ errcontext("PL/Python procedure \"%s\"",
+ PLy_procedure_name(exec_ctx->curr_proc));
+ else
+ errcontext("PL/Python function \"%s\"",
+ PLy_procedure_name(exec_ctx->curr_proc));
+ }
}
static void
proc->fn_tid = procTup->t_self;
proc->fn_readonly = (procStruct->provolatile != PROVOLATILE_VOLATILE);
proc->is_setof = procStruct->proretset;
+ proc->is_procedure = (procStruct->prorettype == InvalidOid);
proc->src = NULL;
proc->argnames = NULL;
proc->args = NULL;
/*
* get information required for output conversion of the return value,
- * but only if this isn't a trigger.
+ * but only if this isn't a trigger or procedure.
*/
- if (!is_trigger)
+ if (!is_trigger && procStruct->prorettype)
{
Oid rettype = procStruct->prorettype;
HeapTuple rvTypeTup;
TransactionId fn_xmin;
ItemPointerData fn_tid;
bool fn_readonly;
- bool is_setof; /* true, if procedure returns result set */
+ bool is_setof; /* true, if function returns result set */
+ bool is_procedure;
PLyObToDatum result; /* Function result output conversion info */
PLyDatumToOb result_in; /* For converting input tuples in a trigger */
char *src; /* textual procedure code, after mangling */
--- /dev/null
+--
+-- Tests for procedures / CALL syntax
+--
+
+CREATE PROCEDURE test_proc1()
+LANGUAGE plpythonu
+AS $$
+pass
+$$;
+
+CALL test_proc1();
+
+
+-- error: can't return non-None
+CREATE PROCEDURE test_proc2()
+LANGUAGE plpythonu
+AS $$
+return 5
+$$;
+
+CALL test_proc2();
+
+
+CREATE TABLE test1 (a int);
+
+CREATE PROCEDURE test_proc3(x int)
+LANGUAGE plpythonu
+AS $$
+plpy.execute("INSERT INTO test1 VALUES (%s)" % x)
+$$;
+
+CALL test_proc3(55);
+
+SELECT * FROM test1;
+
+
+DROP PROCEDURE test_proc1;
+DROP PROCEDURE test_proc2;
+DROP PROCEDURE test_proc3;
+
+DROP TABLE test1;
pltclu.control pltclu--1.0.sql pltclu--unpackaged--1.0.sql
REGRESS_OPTS = --dbname=$(PL_TESTDB) --load-extension=pltcl
-REGRESS = pltcl_setup pltcl_queries pltcl_start_proc pltcl_subxact pltcl_unicode
+REGRESS = pltcl_setup pltcl_queries pltcl_call pltcl_start_proc pltcl_subxact pltcl_unicode
# Tcl on win32 ships with import libraries only for Microsoft Visual C++,
# which are not compatible with mingw gcc. Therefore we need to build a
--- /dev/null
+CREATE PROCEDURE test_proc1()
+LANGUAGE pltcl
+AS $$
+unset
+$$;
+CALL test_proc1();
+CREATE PROCEDURE test_proc2()
+LANGUAGE pltcl
+AS $$
+return 5
+$$;
+CALL test_proc2();
+CREATE TABLE test1 (a int);
+CREATE PROCEDURE test_proc3(x int)
+LANGUAGE pltcl
+AS $$
+spi_exec "INSERT INTO test1 VALUES ($1)"
+$$;
+CALL test_proc3(55);
+SELECT * FROM test1;
+ a
+----
+ 55
+(1 row)
+
+DROP PROCEDURE test_proc1;
+DROP PROCEDURE test_proc2;
+DROP PROCEDURE test_proc3;
+DROP TABLE test1;
Oid result_typid; /* OID of fn's result type */
FmgrInfo result_in_func; /* input function for fn's result type */
Oid result_typioparam; /* param to pass to same */
+ bool fn_is_procedure;/* true if this is a procedure */
bool fn_retisset; /* true if function returns a set */
bool fn_retistuple; /* true if function returns composite */
bool fn_retisdomain; /* true if function returns domain */
retval = (Datum) 0;
fcinfo->isnull = true;
}
- else if (fcinfo->isnull)
+ else if (fcinfo->isnull && !prodesc->fn_is_procedure)
{
retval = InputFunctionCall(&prodesc->result_in_func,
NULL,
call_state);
retval = HeapTupleGetDatum(tup);
}
- else
+ else if (!prodesc->fn_is_procedure)
retval = InputFunctionCall(&prodesc->result_in_func,
utf_u2e(Tcl_GetStringResult(interp)),
prodesc->result_typioparam,
-1);
+ else
+ retval = 0;
return retval;
}
* Get the required information for input conversion of the
* return value.
************************************************************/
- if (!is_trigger && !is_event_trigger)
+ prodesc->fn_is_procedure = (procStruct->prorettype == InvalidOid);
+
+ if (!is_trigger && !is_event_trigger && procStruct->prorettype)
{
Oid rettype = procStruct->prorettype;
tuplestore_puttuple(call_state->tuple_store, tuple);
}
}
- else
+ else if (!prodesc->fn_is_procedure)
{
Datum retval;
bool isNull = false;
--- /dev/null
+CREATE PROCEDURE test_proc1()
+LANGUAGE pltcl
+AS $$
+unset
+$$;
+
+CALL test_proc1();
+
+
+CREATE PROCEDURE test_proc2()
+LANGUAGE pltcl
+AS $$
+return 5
+$$;
+
+CALL test_proc2();
+
+
+CREATE TABLE test1 (a int);
+
+CREATE PROCEDURE test_proc3(x int)
+LANGUAGE pltcl
+AS $$
+spi_exec "INSERT INTO test1 VALUES ($1)"
+$$;
+
+CALL test_proc3(55);
+
+SELECT * FROM test1;
+
+
+DROP PROCEDURE test_proc1;
+DROP PROCEDURE test_proc2;
+DROP PROCEDURE test_proc3;
+
+DROP TABLE test1;
--- /dev/null
+CALL nonexistent(); -- error
+ERROR: function nonexistent() does not exist
+LINE 1: CALL nonexistent();
+ ^
+HINT: No function matches the given name and argument types. You might need to add explicit type casts.
+CALL random(); -- error
+ERROR: random() is not a procedure
+LINE 1: CALL random();
+ ^
+HINT: To call a function, use SELECT.
+CREATE FUNCTION testfunc1(a int) RETURNS int LANGUAGE SQL AS $$ SELECT a $$;
+CREATE TABLE cp_test (a int, b text);
+CREATE PROCEDURE ptest1(x text)
+LANGUAGE SQL
+AS $$
+INSERT INTO cp_test VALUES (1, x);
+$$;
+SELECT ptest1('x'); -- error
+ERROR: ptest1(unknown) is a procedure
+LINE 1: SELECT ptest1('x');
+ ^
+HINT: To call a procedure, use CALL.
+CALL ptest1('a'); -- ok
+\df ptest1
+ List of functions
+ Schema | Name | Result data type | Argument data types | Type
+--------+--------+------------------+---------------------+------
+ public | ptest1 | | x text | proc
+(1 row)
+
+SELECT * FROM cp_test ORDER BY a;
+ a | b
+---+---
+ 1 | a
+(1 row)
+
+CREATE PROCEDURE ptest2()
+LANGUAGE SQL
+AS $$
+SELECT 5;
+$$;
+CALL ptest2();
+-- various error cases
+CREATE PROCEDURE ptestx() LANGUAGE SQL WINDOW AS $$ INSERT INTO cp_test VALUES (1, 'a') $$;
+ERROR: invalid attribute in procedure definition
+LINE 1: CREATE PROCEDURE ptestx() LANGUAGE SQL WINDOW AS $$ INSERT I...
+ ^
+CREATE PROCEDURE ptestx() LANGUAGE SQL STRICT AS $$ INSERT INTO cp_test VALUES (1, 'a') $$;
+ERROR: invalid attribute in procedure definition
+LINE 1: CREATE PROCEDURE ptestx() LANGUAGE SQL STRICT AS $$ INSERT I...
+ ^
+CREATE PROCEDURE ptestx(OUT a int) LANGUAGE SQL AS $$ INSERT INTO cp_test VALUES (1, 'a') $$;
+ERROR: procedures cannot have OUT parameters
+ALTER PROCEDURE ptest1(text) STRICT;
+ERROR: invalid attribute in procedure definition
+LINE 1: ALTER PROCEDURE ptest1(text) STRICT;
+ ^
+ALTER FUNCTION ptest1(text) VOLATILE; -- error: not a function
+ERROR: ptest1(text) is not a function
+ALTER PROCEDURE testfunc1(int) VOLATILE; -- error: not a procedure
+ERROR: testfunc1(integer) is not a procedure
+ALTER PROCEDURE nonexistent() VOLATILE;
+ERROR: procedure nonexistent() does not exist
+DROP FUNCTION ptest1(text); -- error: not a function
+ERROR: ptest1(text) is not a function
+DROP PROCEDURE testfunc1(int); -- error: not a procedure
+ERROR: testfunc1(integer) is not a procedure
+DROP PROCEDURE nonexistent();
+ERROR: procedure nonexistent() does not exist
+-- privileges
+CREATE USER regress_user1;
+GRANT INSERT ON cp_test TO regress_user1;
+REVOKE EXECUTE ON PROCEDURE ptest1(text) FROM PUBLIC;
+SET ROLE regress_user1;
+CALL ptest1('a'); -- error
+ERROR: permission denied for function ptest1
+RESET ROLE;
+GRANT EXECUTE ON PROCEDURE ptest1(text) TO regress_user1;
+SET ROLE regress_user1;
+CALL ptest1('a'); -- ok
+RESET ROLE;
+-- ROUTINE syntax
+ALTER ROUTINE testfunc1(int) RENAME TO testfunc1a;
+ALTER ROUTINE testfunc1a RENAME TO testfunc1;
+ALTER ROUTINE ptest1(text) RENAME TO ptest1a;
+ALTER ROUTINE ptest1a RENAME TO ptest1;
+DROP ROUTINE testfunc1(int);
+-- cleanup
+DROP PROCEDURE ptest1;
+DROP PROCEDURE ptest2;
+DROP TABLE cp_test;
+DROP USER regress_user1;
CREATE FUNCTION addr_nsp.trig() RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN END; $$;
CREATE TRIGGER t BEFORE INSERT ON addr_nsp.gentable FOR EACH ROW EXECUTE PROCEDURE addr_nsp.trig();
CREATE POLICY genpol ON addr_nsp.gentable;
+CREATE PROCEDURE addr_nsp.proc(int4) LANGUAGE SQL AS $$ $$;
CREATE SERVER "integer" FOREIGN DATA WRAPPER addr_fdw;
CREATE USER MAPPING FOR regress_addr_user SERVER "integer";
ALTER DEFAULT PRIVILEGES FOR ROLE regress_addr_user IN SCHEMA public GRANT ALL ON TABLES TO regress_addr_user;
('table'), ('index'), ('sequence'), ('view'),
('materialized view'), ('foreign table'),
('table column'), ('foreign table column'),
- ('aggregate'), ('function'), ('type'), ('cast'),
+ ('aggregate'), ('function'), ('procedure'), ('type'), ('cast'),
('table constraint'), ('domain constraint'), ('conversion'), ('default value'),
('operator'), ('operator class'), ('operator family'), ('rule'), ('trigger'),
('text search parser'), ('text search dictionary'),
WARNING: error for function,{addr_nsp,zwei},{integer}: function addr_nsp.zwei(integer) does not exist
WARNING: error for function,{eins,zwei,drei},{}: cross-database references are not implemented: eins.zwei.drei
WARNING: error for function,{eins,zwei,drei},{integer}: cross-database references are not implemented: eins.zwei.drei
+WARNING: error for procedure,{eins},{}: procedure eins() does not exist
+WARNING: error for procedure,{eins},{integer}: procedure eins(integer) does not exist
+WARNING: error for procedure,{addr_nsp,zwei},{}: procedure addr_nsp.zwei() does not exist
+WARNING: error for procedure,{addr_nsp,zwei},{integer}: procedure addr_nsp.zwei(integer) does not exist
+WARNING: error for procedure,{eins,zwei,drei},{}: cross-database references are not implemented: eins.zwei.drei
+WARNING: error for procedure,{eins,zwei,drei},{integer}: cross-database references are not implemented: eins.zwei.drei
WARNING: error for type,{eins},{}: type "eins" does not exist
WARNING: error for type,{eins},{integer}: type "eins" does not exist
WARNING: error for type,{addr_nsp,zwei},{}: name list length must be exactly 1
('foreign table column', '{addr_nsp, genftable, a}', '{}'),
('aggregate', '{addr_nsp, genaggr}', '{int4}'),
('function', '{pg_catalog, pg_identify_object}', '{pg_catalog.oid, pg_catalog.oid, int4}'),
+ ('procedure', '{addr_nsp, proc}', '{int4}'),
('type', '{pg_catalog._int4}', '{}'),
('type', '{addr_nsp.gendomain}', '{}'),
('type', '{addr_nsp.gencomptype}', '{}'),
type | addr_nsp | gendomain | addr_nsp.gendomain | t
function | pg_catalog | | pg_catalog.pg_identify_object(pg_catalog.oid,pg_catalog.oid,integer) | t
aggregate | addr_nsp | | addr_nsp.genaggr(integer) | t
+ procedure | addr_nsp | | addr_nsp.proc(integer) | t
sequence | addr_nsp | gentable_a_seq | addr_nsp.gentable_a_seq | t
table | addr_nsp | gentable | addr_nsp.gentable | t
table column | addr_nsp | gentable | addr_nsp.gentable.b | t
subscription | | addr_sub | addr_sub | t
publication | | addr_pub | addr_pub | t
publication relation | | | gentable in publication addr_pub | t
-(46 rows)
+(47 rows)
---
--- Cleanup resources
DROP PUBLICATION addr_pub;
DROP SUBSCRIPTION addr_sub;
DROP SCHEMA addr_nsp CASCADE;
-NOTICE: drop cascades to 12 other objects
+NOTICE: drop cascades to 13 other objects
DROP OWNED BY regress_addr_user;
DROP USER regress_addr_user;
ERROR: "x" is not a scalar variable
LINE 3: GET DIAGNOSTICS x = ROW_COUNT;
^
+--
+-- Procedures
+--
+CREATE PROCEDURE test_proc1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+ NULL;
+END;
+$$;
+CALL test_proc1();
+-- error: can't return non-NULL
+CREATE PROCEDURE test_proc2()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+ RETURN 5;
+END;
+$$;
+CALL test_proc2();
+ERROR: cannot return a value from a procedure
+CONTEXT: PL/pgSQL function test_proc2() while casting return value to function's return type
+CREATE TABLE proc_test1 (a int);
+CREATE PROCEDURE test_proc3(x int)
+LANGUAGE plpgsql
+AS $$
+BEGIN
+ INSERT INTO proc_test1 VALUES (x);
+END;
+$$;
+CALL test_proc3(55);
+SELECT * FROM proc_test1;
+ a
+----
+ 55
+(1 row)
+
+DROP PROCEDURE test_proc1;
+DROP PROCEDURE test_proc2;
+DROP PROCEDURE test_proc3;
+DROP TABLE proc_test1;
-- verify it lists properly
\df dfunc
- List of functions
- Schema | Name | Result data type | Argument data types | Type
---------+-------+------------------+-----------------------------------------------------------+--------
- public | dfunc | integer | a integer DEFAULT 1, OUT sum integer, b integer DEFAULT 2 | normal
+ List of functions
+ Schema | Name | Result data type | Argument data types | Type
+--------+-------+------------------+-----------------------------------------------------------+------
+ public | dfunc | integer | a integer DEFAULT 1, OUT sum integer, b integer DEFAULT 2 | func
(1 row)
drop function dfunc(int, int);
ERROR: cannot remove parameter defaults from existing function
HINT: Use DROP FUNCTION dfunc(integer[]) first.
\df dfunc
- List of functions
- Schema | Name | Result data type | Argument data types | Type
---------+-------+------------------+-------------------------------------------------+--------
- public | dfunc | integer | VARIADIC a integer[] DEFAULT ARRAY[]::integer[] | normal
+ List of functions
+ Schema | Name | Result data type | Argument data types | Type
+--------+-------+------------------+-------------------------------------------------+------
+ public | dfunc | integer | VARIADIC a integer[] DEFAULT ARRAY[]::integer[] | func
(1 row)
drop function dfunc(a variadic int[]);
WARNING: no privileges were granted for "sql"
CREATE FUNCTION testfunc1(int) RETURNS int AS 'select 2 * $1;' LANGUAGE sql;
CREATE FUNCTION testfunc2(int) RETURNS int AS 'select 3 * $1;' LANGUAGE sql;
-REVOKE ALL ON FUNCTION testfunc1(int), testfunc2(int) FROM PUBLIC;
-GRANT EXECUTE ON FUNCTION testfunc1(int), testfunc2(int) TO regress_user2;
+CREATE AGGREGATE testagg1(int) (sfunc = int4pl, stype = int4);
+CREATE PROCEDURE testproc1(int) AS 'select $1;' LANGUAGE sql;
+REVOKE ALL ON FUNCTION testfunc1(int), testfunc2(int), testagg1(int) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION testfunc1(int), testfunc2(int), testagg1(int) TO regress_user2;
+REVOKE ALL ON FUNCTION testproc1(int) FROM PUBLIC; -- fail, not a function
+ERROR: testproc1(integer) is not a function
+REVOKE ALL ON PROCEDURE testproc1(int) FROM PUBLIC;
+GRANT EXECUTE ON PROCEDURE testproc1(int) TO regress_user2;
GRANT USAGE ON FUNCTION testfunc1(int) TO regress_user3; -- semantic error
ERROR: invalid privilege type USAGE for function
+GRANT USAGE ON FUNCTION testagg1(int) TO regress_user3; -- semantic error
+ERROR: invalid privilege type USAGE for function
+GRANT USAGE ON PROCEDURE testproc1(int) TO regress_user3; -- semantic error
+ERROR: invalid privilege type USAGE for procedure
GRANT ALL PRIVILEGES ON FUNCTION testfunc1(int) TO regress_user4;
GRANT ALL PRIVILEGES ON FUNCTION testfunc_nosuch(int) TO regress_user4;
ERROR: function testfunc_nosuch(integer) does not exist
+GRANT ALL PRIVILEGES ON FUNCTION testagg1(int) TO regress_user4;
+GRANT ALL PRIVILEGES ON PROCEDURE testproc1(int) TO regress_user4;
CREATE FUNCTION testfunc4(boolean) RETURNS text
AS 'select col1 from atest2 where col2 = $1;'
LANGUAGE sql SECURITY DEFINER;
CREATE FUNCTION testfunc3(int) RETURNS int AS 'select 2 * $1;' LANGUAGE sql; -- fail
ERROR: permission denied for language sql
+SELECT testagg1(x) FROM (VALUES (1), (2), (3)) _(x); -- ok
+ testagg1
+----------
+ 6
+(1 row)
+
+CALL testproc1(6); -- ok
SET SESSION AUTHORIZATION regress_user3;
SELECT testfunc1(5); -- fail
ERROR: permission denied for function testfunc1
+SELECT testagg1(x) FROM (VALUES (1), (2), (3)) _(x); -- fail
+ERROR: permission denied for function testagg1
+CALL testproc1(6); -- fail
+ERROR: permission denied for function testproc1
SELECT col1 FROM atest2 WHERE col2 = true; -- fail
ERROR: permission denied for relation atest2
SELECT testfunc4(true); -- ok
10
(1 row)
+SELECT testagg1(x) FROM (VALUES (1), (2), (3)) _(x); -- ok
+ testagg1
+----------
+ 6
+(1 row)
+
+CALL testproc1(6); -- ok
DROP FUNCTION testfunc1(int); -- fail
ERROR: must be owner of function testfunc1
+DROP AGGREGATE testagg1(int); -- fail
+ERROR: must be owner of function testagg1
+DROP PROCEDURE testproc1(int); -- fail
+ERROR: must be owner of function testproc1
\c -
DROP FUNCTION testfunc1(int); -- ok
-- restore to sanity
SET ROLE regress_user1;
CREATE FUNCTION testns.foo() RETURNS int AS 'select 1' LANGUAGE sql;
+CREATE AGGREGATE testns.agg1(int) (sfunc = int4pl, stype = int4);
+CREATE PROCEDURE testns.bar() AS 'select 1' LANGUAGE sql;
SELECT has_function_privilege('regress_user2', 'testns.foo()', 'EXECUTE'); -- no
has_function_privilege
------------------------
f
(1 row)
-ALTER DEFAULT PRIVILEGES IN SCHEMA testns GRANT EXECUTE ON FUNCTIONS to public;
+SELECT has_function_privilege('regress_user2', 'testns.agg1(int)', 'EXECUTE'); -- no
+ has_function_privilege
+------------------------
+ f
+(1 row)
+
+SELECT has_function_privilege('regress_user2', 'testns.bar()', 'EXECUTE'); -- no
+ has_function_privilege
+------------------------
+ f
+(1 row)
+
+ALTER DEFAULT PRIVILEGES IN SCHEMA testns GRANT EXECUTE ON ROUTINES to public;
DROP FUNCTION testns.foo();
CREATE FUNCTION testns.foo() RETURNS int AS 'select 1' LANGUAGE sql;
+DROP AGGREGATE testns.agg1(int);
+CREATE AGGREGATE testns.agg1(int) (sfunc = int4pl, stype = int4);
+DROP PROCEDURE testns.bar();
+CREATE PROCEDURE testns.bar() AS 'select 1' LANGUAGE sql;
SELECT has_function_privilege('regress_user2', 'testns.foo()', 'EXECUTE'); -- yes
has_function_privilege
------------------------
t
(1 row)
+SELECT has_function_privilege('regress_user2', 'testns.agg1(int)', 'EXECUTE'); -- yes
+ has_function_privilege
+------------------------
+ t
+(1 row)
+
+SELECT has_function_privilege('regress_user2', 'testns.bar()', 'EXECUTE'); -- yes (counts as function here)
+ has_function_privilege
+------------------------
+ t
+(1 row)
+
DROP FUNCTION testns.foo();
+DROP AGGREGATE testns.agg1(int);
+DROP PROCEDURE testns.bar();
ALTER DEFAULT PRIVILEGES FOR ROLE regress_user1 REVOKE USAGE ON TYPES FROM public;
CREATE DOMAIN testns.testdomain1 AS int;
SELECT has_type_privilege('regress_user2', 'testns.testdomain1', 'USAGE'); -- no
(1 row)
CREATE FUNCTION testns.testfunc(int) RETURNS int AS 'select 3 * $1;' LANGUAGE sql;
+CREATE AGGREGATE testns.testagg(int) (sfunc = int4pl, stype = int4);
+CREATE PROCEDURE testns.testproc(int) AS 'select 3' LANGUAGE sql;
SELECT has_function_privilege('regress_user1', 'testns.testfunc(int)', 'EXECUTE'); -- true by default
has_function_privilege
------------------------
t
(1 row)
+SELECT has_function_privilege('regress_user1', 'testns.testagg(int)', 'EXECUTE'); -- true by default
+ has_function_privilege
+------------------------
+ t
+(1 row)
+
+SELECT has_function_privilege('regress_user1', 'testns.testproc(int)', 'EXECUTE'); -- true by default
+ has_function_privilege
+------------------------
+ t
+(1 row)
+
REVOKE ALL ON ALL FUNCTIONS IN SCHEMA testns FROM PUBLIC;
SELECT has_function_privilege('regress_user1', 'testns.testfunc(int)', 'EXECUTE'); -- false
has_function_privilege
f
(1 row)
+SELECT has_function_privilege('regress_user1', 'testns.testagg(int)', 'EXECUTE'); -- false
+ has_function_privilege
+------------------------
+ f
+(1 row)
+
+SELECT has_function_privilege('regress_user1', 'testns.testproc(int)', 'EXECUTE'); -- still true, not a function
+ has_function_privilege
+------------------------
+ t
+(1 row)
+
+REVOKE ALL ON ALL PROCEDURES IN SCHEMA testns FROM PUBLIC;
+SELECT has_function_privilege('regress_user1', 'testns.testproc(int)', 'EXECUTE'); -- now false
+ has_function_privilege
+------------------------
+ f
+(1 row)
+
+GRANT ALL ON ALL ROUTINES IN SCHEMA testns TO PUBLIC;
+SELECT has_function_privilege('regress_user1', 'testns.testfunc(int)', 'EXECUTE'); -- true
+ has_function_privilege
+------------------------
+ t
+(1 row)
+
+SELECT has_function_privilege('regress_user1', 'testns.testagg(int)', 'EXECUTE'); -- true
+ has_function_privilege
+------------------------
+ t
+(1 row)
+
+SELECT has_function_privilege('regress_user1', 'testns.testproc(int)', 'EXECUTE'); -- true
+ has_function_privilege
+------------------------
+ t
+(1 row)
+
\set VERBOSITY terse \\ -- suppress cascade details
DROP SCHEMA testns CASCADE;
-NOTICE: drop cascades to 3 other objects
+NOTICE: drop cascades to 5 other objects
\set VERBOSITY default
-- Change owner of the schema & and rename of new schema owner
\c -
-- clean up
\c
drop sequence x_seq;
+DROP AGGREGATE testagg1(int);
DROP FUNCTION testfunc2(int);
DROP FUNCTION testfunc4(boolean);
+DROP PROCEDURE testproc1(int);
DROP VIEW atestv0;
DROP VIEW atestv1;
DROP VIEW atestv2;
# ----------
# More groups of parallel tests
# ----------
-test: create_misc create_operator
+test: create_misc create_operator create_procedure
# These depend on the above two
test: create_index create_view
test: copydml
test: create_misc
test: create_operator
+test: create_procedure
test: create_index
test: create_view
test: create_aggregate
--- /dev/null
+CALL nonexistent(); -- error
+CALL random(); -- error
+
+CREATE FUNCTION testfunc1(a int) RETURNS int LANGUAGE SQL AS $$ SELECT a $$;
+
+CREATE TABLE cp_test (a int, b text);
+
+CREATE PROCEDURE ptest1(x text)
+LANGUAGE SQL
+AS $$
+INSERT INTO cp_test VALUES (1, x);
+$$;
+
+SELECT ptest1('x'); -- error
+CALL ptest1('a'); -- ok
+
+\df ptest1
+
+SELECT * FROM cp_test ORDER BY a;
+
+
+CREATE PROCEDURE ptest2()
+LANGUAGE SQL
+AS $$
+SELECT 5;
+$$;
+
+CALL ptest2();
+
+
+-- various error cases
+
+CREATE PROCEDURE ptestx() LANGUAGE SQL WINDOW AS $$ INSERT INTO cp_test VALUES (1, 'a') $$;
+CREATE PROCEDURE ptestx() LANGUAGE SQL STRICT AS $$ INSERT INTO cp_test VALUES (1, 'a') $$;
+CREATE PROCEDURE ptestx(OUT a int) LANGUAGE SQL AS $$ INSERT INTO cp_test VALUES (1, 'a') $$;
+
+ALTER PROCEDURE ptest1(text) STRICT;
+ALTER FUNCTION ptest1(text) VOLATILE; -- error: not a function
+ALTER PROCEDURE testfunc1(int) VOLATILE; -- error: not a procedure
+ALTER PROCEDURE nonexistent() VOLATILE;
+
+DROP FUNCTION ptest1(text); -- error: not a function
+DROP PROCEDURE testfunc1(int); -- error: not a procedure
+DROP PROCEDURE nonexistent();
+
+
+-- privileges
+
+CREATE USER regress_user1;
+GRANT INSERT ON cp_test TO regress_user1;
+REVOKE EXECUTE ON PROCEDURE ptest1(text) FROM PUBLIC;
+SET ROLE regress_user1;
+CALL ptest1('a'); -- error
+RESET ROLE;
+GRANT EXECUTE ON PROCEDURE ptest1(text) TO regress_user1;
+SET ROLE regress_user1;
+CALL ptest1('a'); -- ok
+RESET ROLE;
+
+
+-- ROUTINE syntax
+
+ALTER ROUTINE testfunc1(int) RENAME TO testfunc1a;
+ALTER ROUTINE testfunc1a RENAME TO testfunc1;
+
+ALTER ROUTINE ptest1(text) RENAME TO ptest1a;
+ALTER ROUTINE ptest1a RENAME TO ptest1;
+
+DROP ROUTINE testfunc1(int);
+
+
+-- cleanup
+
+DROP PROCEDURE ptest1;
+DROP PROCEDURE ptest2;
+
+DROP TABLE cp_test;
+
+DROP USER regress_user1;
CREATE FUNCTION addr_nsp.trig() RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN END; $$;
CREATE TRIGGER t BEFORE INSERT ON addr_nsp.gentable FOR EACH ROW EXECUTE PROCEDURE addr_nsp.trig();
CREATE POLICY genpol ON addr_nsp.gentable;
+CREATE PROCEDURE addr_nsp.proc(int4) LANGUAGE SQL AS $$ $$;
CREATE SERVER "integer" FOREIGN DATA WRAPPER addr_fdw;
CREATE USER MAPPING FOR regress_addr_user SERVER "integer";
ALTER DEFAULT PRIVILEGES FOR ROLE regress_addr_user IN SCHEMA public GRANT ALL ON TABLES TO regress_addr_user;
('table'), ('index'), ('sequence'), ('view'),
('materialized view'), ('foreign table'),
('table column'), ('foreign table column'),
- ('aggregate'), ('function'), ('type'), ('cast'),
+ ('aggregate'), ('function'), ('procedure'), ('type'), ('cast'),
('table constraint'), ('domain constraint'), ('conversion'), ('default value'),
('operator'), ('operator class'), ('operator family'), ('rule'), ('trigger'),
('text search parser'), ('text search dictionary'),
('foreign table column', '{addr_nsp, genftable, a}', '{}'),
('aggregate', '{addr_nsp, genaggr}', '{int4}'),
('function', '{pg_catalog, pg_identify_object}', '{pg_catalog.oid, pg_catalog.oid, int4}'),
+ ('procedure', '{addr_nsp, proc}', '{int4}'),
('type', '{pg_catalog._int4}', '{}'),
('type', '{addr_nsp.gendomain}', '{}'),
('type', '{addr_nsp.gencomptype}', '{}'),
GET DIAGNOSTICS x = ROW_COUNT;
RETURN;
END; $$ LANGUAGE plpgsql;
+
+
+--
+-- Procedures
+--
+
+CREATE PROCEDURE test_proc1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+ NULL;
+END;
+$$;
+
+CALL test_proc1();
+
+
+-- error: can't return non-NULL
+CREATE PROCEDURE test_proc2()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+ RETURN 5;
+END;
+$$;
+
+CALL test_proc2();
+
+
+CREATE TABLE proc_test1 (a int);
+
+CREATE PROCEDURE test_proc3(x int)
+LANGUAGE plpgsql
+AS $$
+BEGIN
+ INSERT INTO proc_test1 VALUES (x);
+END;
+$$;
+
+CALL test_proc3(55);
+
+SELECT * FROM proc_test1;
+
+
+DROP PROCEDURE test_proc1;
+DROP PROCEDURE test_proc2;
+DROP PROCEDURE test_proc3;
+
+DROP TABLE proc_test1;
GRANT USAGE ON LANGUAGE sql TO regress_user2; -- fail
CREATE FUNCTION testfunc1(int) RETURNS int AS 'select 2 * $1;' LANGUAGE sql;
CREATE FUNCTION testfunc2(int) RETURNS int AS 'select 3 * $1;' LANGUAGE sql;
-
-REVOKE ALL ON FUNCTION testfunc1(int), testfunc2(int) FROM PUBLIC;
-GRANT EXECUTE ON FUNCTION testfunc1(int), testfunc2(int) TO regress_user2;
+CREATE AGGREGATE testagg1(int) (sfunc = int4pl, stype = int4);
+CREATE PROCEDURE testproc1(int) AS 'select $1;' LANGUAGE sql;
+
+REVOKE ALL ON FUNCTION testfunc1(int), testfunc2(int), testagg1(int) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION testfunc1(int), testfunc2(int), testagg1(int) TO regress_user2;
+REVOKE ALL ON FUNCTION testproc1(int) FROM PUBLIC; -- fail, not a function
+REVOKE ALL ON PROCEDURE testproc1(int) FROM PUBLIC;
+GRANT EXECUTE ON PROCEDURE testproc1(int) TO regress_user2;
GRANT USAGE ON FUNCTION testfunc1(int) TO regress_user3; -- semantic error
+GRANT USAGE ON FUNCTION testagg1(int) TO regress_user3; -- semantic error
+GRANT USAGE ON PROCEDURE testproc1(int) TO regress_user3; -- semantic error
GRANT ALL PRIVILEGES ON FUNCTION testfunc1(int) TO regress_user4;
GRANT ALL PRIVILEGES ON FUNCTION testfunc_nosuch(int) TO regress_user4;
+GRANT ALL PRIVILEGES ON FUNCTION testagg1(int) TO regress_user4;
+GRANT ALL PRIVILEGES ON PROCEDURE testproc1(int) TO regress_user4;
CREATE FUNCTION testfunc4(boolean) RETURNS text
AS 'select col1 from atest2 where col2 = $1;'
SET SESSION AUTHORIZATION regress_user2;
SELECT testfunc1(5), testfunc2(5); -- ok
CREATE FUNCTION testfunc3(int) RETURNS int AS 'select 2 * $1;' LANGUAGE sql; -- fail
+SELECT testagg1(x) FROM (VALUES (1), (2), (3)) _(x); -- ok
+CALL testproc1(6); -- ok
SET SESSION AUTHORIZATION regress_user3;
SELECT testfunc1(5); -- fail
+SELECT testagg1(x) FROM (VALUES (1), (2), (3)) _(x); -- fail
+CALL testproc1(6); -- fail
SELECT col1 FROM atest2 WHERE col2 = true; -- fail
SELECT testfunc4(true); -- ok
SET SESSION AUTHORIZATION regress_user4;
SELECT testfunc1(5); -- ok
+SELECT testagg1(x) FROM (VALUES (1), (2), (3)) _(x); -- ok
+CALL testproc1(6); -- ok
DROP FUNCTION testfunc1(int); -- fail
+DROP AGGREGATE testagg1(int); -- fail
+DROP PROCEDURE testproc1(int); -- fail
\c -
SET ROLE regress_user1;
CREATE FUNCTION testns.foo() RETURNS int AS 'select 1' LANGUAGE sql;
+CREATE AGGREGATE testns.agg1(int) (sfunc = int4pl, stype = int4);
+CREATE PROCEDURE testns.bar() AS 'select 1' LANGUAGE sql;
SELECT has_function_privilege('regress_user2', 'testns.foo()', 'EXECUTE'); -- no
+SELECT has_function_privilege('regress_user2', 'testns.agg1(int)', 'EXECUTE'); -- no
+SELECT has_function_privilege('regress_user2', 'testns.bar()', 'EXECUTE'); -- no
-ALTER DEFAULT PRIVILEGES IN SCHEMA testns GRANT EXECUTE ON FUNCTIONS to public;
+ALTER DEFAULT PRIVILEGES IN SCHEMA testns GRANT EXECUTE ON ROUTINES to public;
DROP FUNCTION testns.foo();
CREATE FUNCTION testns.foo() RETURNS int AS 'select 1' LANGUAGE sql;
+DROP AGGREGATE testns.agg1(int);
+CREATE AGGREGATE testns.agg1(int) (sfunc = int4pl, stype = int4);
+DROP PROCEDURE testns.bar();
+CREATE PROCEDURE testns.bar() AS 'select 1' LANGUAGE sql;
SELECT has_function_privilege('regress_user2', 'testns.foo()', 'EXECUTE'); -- yes
+SELECT has_function_privilege('regress_user2', 'testns.agg1(int)', 'EXECUTE'); -- yes
+SELECT has_function_privilege('regress_user2', 'testns.bar()', 'EXECUTE'); -- yes (counts as function here)
DROP FUNCTION testns.foo();
+DROP AGGREGATE testns.agg1(int);
+DROP PROCEDURE testns.bar();
ALTER DEFAULT PRIVILEGES FOR ROLE regress_user1 REVOKE USAGE ON TYPES FROM public;
SELECT has_table_privilege('regress_user1', 'testns.t2', 'SELECT'); -- false
CREATE FUNCTION testns.testfunc(int) RETURNS int AS 'select 3 * $1;' LANGUAGE sql;
+CREATE AGGREGATE testns.testagg(int) (sfunc = int4pl, stype = int4);
+CREATE PROCEDURE testns.testproc(int) AS 'select 3' LANGUAGE sql;
SELECT has_function_privilege('regress_user1', 'testns.testfunc(int)', 'EXECUTE'); -- true by default
+SELECT has_function_privilege('regress_user1', 'testns.testagg(int)', 'EXECUTE'); -- true by default
+SELECT has_function_privilege('regress_user1', 'testns.testproc(int)', 'EXECUTE'); -- true by default
REVOKE ALL ON ALL FUNCTIONS IN SCHEMA testns FROM PUBLIC;
SELECT has_function_privilege('regress_user1', 'testns.testfunc(int)', 'EXECUTE'); -- false
+SELECT has_function_privilege('regress_user1', 'testns.testagg(int)', 'EXECUTE'); -- false
+SELECT has_function_privilege('regress_user1', 'testns.testproc(int)', 'EXECUTE'); -- still true, not a function
+
+REVOKE ALL ON ALL PROCEDURES IN SCHEMA testns FROM PUBLIC;
+
+SELECT has_function_privilege('regress_user1', 'testns.testproc(int)', 'EXECUTE'); -- now false
+
+GRANT ALL ON ALL ROUTINES IN SCHEMA testns TO PUBLIC;
+
+SELECT has_function_privilege('regress_user1', 'testns.testfunc(int)', 'EXECUTE'); -- true
+SELECT has_function_privilege('regress_user1', 'testns.testagg(int)', 'EXECUTE'); -- true
+SELECT has_function_privilege('regress_user1', 'testns.testproc(int)', 'EXECUTE'); -- true
\set VERBOSITY terse \\ -- suppress cascade details
DROP SCHEMA testns CASCADE;
drop sequence x_seq;
+DROP AGGREGATE testagg1(int);
DROP FUNCTION testfunc2(int);
DROP FUNCTION testfunc4(boolean);
+DROP PROCEDURE testproc1(int);
DROP VIEW atestv0;
DROP VIEW atestv1;