]> granicus.if.org Git - postgresql/commitdiff
SQL procedures
authorPeter Eisentraut <peter_e@gmx.net>
Thu, 30 Nov 2017 13:46:13 +0000 (08:46 -0500)
committerPeter Eisentraut <peter_e@gmx.net>
Thu, 30 Nov 2017 16:03:20 +0000 (11:03 -0500)
This adds a new object type "procedure" that is similar to a function
but does not have a return type and is invoked by the new CALL statement
instead of SELECT or similar.  This implementation is aligned with the
SQL standard and compatible with or similar to other SQL implementations.

This commit adds new commands CALL, CREATE/ALTER/DROP PROCEDURE, as well
as ALTER/DROP ROUTINE that can refer to either a function or a
procedure (or an aggregate function, as an extension to SQL).  There is
also support for procedures in various utility commands such as COMMENT
and GRANT, as well as support in pg_dump and psql.  Support for defining
procedures is available in all the languages supplied by the core
distribution.

While this commit is mainly syntax sugar around existing functionality,
future features will rely on having procedures as a separate object
type.

Reviewed-by: Andrew Dunstan <andrew.dunstan@2ndquadrant.com>
92 files changed:
doc/src/sgml/catalogs.sgml
doc/src/sgml/ddl.sgml
doc/src/sgml/ecpg.sgml
doc/src/sgml/information_schema.sgml
doc/src/sgml/plperl.sgml
doc/src/sgml/plpgsql.sgml
doc/src/sgml/plpython.sgml
doc/src/sgml/pltcl.sgml
doc/src/sgml/ref/allfiles.sgml
doc/src/sgml/ref/alter_default_privileges.sgml
doc/src/sgml/ref/alter_extension.sgml
doc/src/sgml/ref/alter_function.sgml
doc/src/sgml/ref/alter_procedure.sgml [new file with mode: 0644]
doc/src/sgml/ref/alter_routine.sgml [new file with mode: 0644]
doc/src/sgml/ref/call.sgml [new file with mode: 0644]
doc/src/sgml/ref/comment.sgml
doc/src/sgml/ref/create_function.sgml
doc/src/sgml/ref/create_procedure.sgml [new file with mode: 0644]
doc/src/sgml/ref/drop_function.sgml
doc/src/sgml/ref/drop_procedure.sgml [new file with mode: 0644]
doc/src/sgml/ref/drop_routine.sgml [new file with mode: 0644]
doc/src/sgml/ref/grant.sgml
doc/src/sgml/ref/revoke.sgml
doc/src/sgml/ref/security_label.sgml
doc/src/sgml/reference.sgml
doc/src/sgml/xfunc.sgml
src/backend/catalog/aclchk.c
src/backend/catalog/information_schema.sql
src/backend/catalog/objectaddress.c
src/backend/catalog/pg_proc.c
src/backend/commands/aggregatecmds.c
src/backend/commands/alter.c
src/backend/commands/dropcmds.c
src/backend/commands/event_trigger.c
src/backend/commands/functioncmds.c
src/backend/commands/opclasscmds.c
src/backend/executor/functions.c
src/backend/nodes/copyfuncs.c
src/backend/nodes/equalfuncs.c
src/backend/optimizer/util/clauses.c
src/backend/parser/gram.y
src/backend/parser/parse_agg.c
src/backend/parser/parse_expr.c
src/backend/parser/parse_func.c
src/backend/tcop/utility.c
src/backend/utils/adt/ruleutils.c
src/backend/utils/cache/lsyscache.c
src/bin/pg_dump/dumputils.c
src/bin/pg_dump/pg_backup_archiver.c
src/bin/pg_dump/pg_dump.c
src/bin/pg_dump/t/002_pg_dump.pl
src/bin/psql/describe.c
src/bin/psql/tab-complete.c
src/include/catalog/catversion.h
src/include/commands/defrem.h
src/include/nodes/nodes.h
src/include/nodes/parsenodes.h
src/include/parser/kwlist.h
src/include/parser/parse_func.h
src/include/parser/parse_node.h
src/include/utils/lsyscache.h
src/interfaces/ecpg/preproc/ecpg.tokens
src/interfaces/ecpg/preproc/ecpg.trailer
src/interfaces/ecpg/preproc/ecpg_keywords.c
src/pl/plperl/GNUmakefile
src/pl/plperl/expected/plperl_call.out [new file with mode: 0644]
src/pl/plperl/plperl.c
src/pl/plperl/sql/plperl_call.sql [new file with mode: 0644]
src/pl/plpgsql/src/pl_comp.c
src/pl/plpgsql/src/pl_exec.c
src/pl/plpython/Makefile
src/pl/plpython/expected/plpython_call.out [new file with mode: 0644]
src/pl/plpython/plpy_exec.c
src/pl/plpython/plpy_main.c
src/pl/plpython/plpy_procedure.c
src/pl/plpython/plpy_procedure.h
src/pl/plpython/sql/plpython_call.sql [new file with mode: 0644]
src/pl/tcl/Makefile
src/pl/tcl/expected/pltcl_call.out [new file with mode: 0644]
src/pl/tcl/pltcl.c
src/pl/tcl/sql/pltcl_call.sql [new file with mode: 0644]
src/test/regress/expected/create_procedure.out [new file with mode: 0644]
src/test/regress/expected/object_address.out
src/test/regress/expected/plpgsql.out
src/test/regress/expected/polymorphism.out
src/test/regress/expected/privileges.out
src/test/regress/parallel_schedule
src/test/regress/serial_schedule
src/test/regress/sql/create_procedure.sql [new file with mode: 0644]
src/test/regress/sql/object_address.sql
src/test/regress/sql/plpgsql.sql
src/test/regress/sql/privileges.sql

index da881a773719bc77f5aa3d4cc508178e4b1850c9..3f02202cafb6adf18e7cb083f5c2052e38233cc4 100644 (file)
@@ -5241,7 +5241,7 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
       <entry><structfield>prorettype</structfield></entry>
       <entry><type>oid</type></entry>
       <entry><literal><link linkend="catalog-pg-type"><structname>pg_type</structname></link>.oid</literal></entry>
-      <entry>Data type of the return value</entry>
+      <entry>Data type of the return value, or null for a procedure</entry>
      </row>
 
      <row>
index e6f50ec819b2212e8cb01e8aad4a32c8fad54b66..9f583266de90d300944be3f1abfaecfe265d749a 100644 (file)
@@ -3947,7 +3947,7 @@ EXPLAIN SELECT count(*) FROM measurement WHERE logdate &gt;= DATE '2008-01-01';
 
    <listitem>
     <para>
-     Functions and operators
+     Functions, procedures, and operators
     </para>
    </listitem>
 
index d1872c1a5c68a832f7fc99e7d5d0d21f68f61635..5a8d1f1b95ba152790347b5e5faca9b9a161f42d 100644 (file)
@@ -4778,7 +4778,9 @@ EXEC SQL WHENEVER <replaceable>condition</replaceable> <replaceable>action</repl
       <term><literal>DO <replaceable>name</replaceable> (<replaceable>args</replaceable>)</literal></term>
       <listitem>
        <para>
-        Call the specified C functions with the specified arguments.
+        Call the specified C functions with the specified arguments.  (This
+        use is different from the meaning of <literal>CALL</literal>
+        and <literal>DO</literal> in the normal PostgreSQL grammar.)
        </para>
       </listitem>
      </varlistentry>
index 99b0ea8519ec831d500c42d883dce30d067dfc3a..0faa72f1d3f11b7d902b3bf3a2e34682014b5812 100644 (file)
@@ -3972,8 +3972,8 @@ ORDER BY c.ordinal_position;
   <title><literal>routines</literal></title>
 
   <para>
-   The view <literal>routines</literal> contains all functions in the
-   current database.  Only those functions are shown that the current
+   The view <literal>routines</literal> contains all functions and procedures in the
+   current database.  Only those functions and procedures are shown that the current
    user has access to (by way of being the owner or having some
    privilege).
   </para>
@@ -4037,8 +4037,8 @@ ORDER BY c.ordinal_position;
       <entry><literal>routine_type</literal></entry>
       <entry><type>character_data</type></entry>
       <entry>
-       Always <literal>FUNCTION</literal> (In the future there might
-       be other types of routines.)
+       <literal>FUNCTION</literal> for a
+       function, <literal>PROCEDURE</literal> for a procedure
       </entry>
      </row>
 
@@ -4087,7 +4087,7 @@ ORDER BY c.ordinal_position;
        the view <literal>element_types</literal>), else
        <literal>USER-DEFINED</literal> (in that case, the type is
        identified in <literal>type_udt_name</literal> and associated
-       columns).
+       columns).  Null for a procedure.
       </entry>
      </row>
 
@@ -4180,7 +4180,7 @@ ORDER BY c.ordinal_position;
       <entry><type>sql_identifier</type></entry>
       <entry>
        Name of the database that the return data type of the function
-       is defined in (always the current database)
+       is defined in (always the current database).  Null for a procedure.
       </entry>
      </row>
 
@@ -4189,7 +4189,7 @@ ORDER BY c.ordinal_position;
       <entry><type>sql_identifier</type></entry>
       <entry>
        Name of the schema that the return data type of the function is
-       defined in
+       defined in.  Null for a procedure.
       </entry>
      </row>
 
@@ -4197,7 +4197,7 @@ ORDER BY c.ordinal_position;
       <entry><literal>type_udt_name</literal></entry>
       <entry><type>sql_identifier</type></entry>
       <entry>
-       Name of the return data type of the function
+       Name of the return data type of the function.  Null for a procedure.
       </entry>
      </row>
 
@@ -4314,7 +4314,7 @@ ORDER BY c.ordinal_position;
       <entry>
        If the function automatically returns null if any of its
        arguments are null, then <literal>YES</literal>, else
-       <literal>NO</literal>.
+       <literal>NO</literal>.  Null for a procedure.
       </entry>
      </row>
 
index 33e39d85e400ebbfc5d99b1fac213833e206e817..100162dead56413e1817fea653d5ce2b222d0313 100644 (file)
@@ -67,6 +67,10 @@ $$ LANGUAGE plperl;
    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:
index 6d14b344487e6f6d29395788c2db0a271239d046..7d23ed437e2a97487ca242f524f9e72b4ba3e9c6 100644 (file)
 
     <para>
      Finally, a <application>PL/pgSQL</application> function can be declared to return
-     <type>void</type> if it has no useful return value.
+     <type>void</type> if it has no useful return value.  (Alternatively, it
+     could be written as a procedure in that case.)
     </para>
 
     <para>
@@ -1865,6 +1866,18 @@ SELECT * FROM get_available_flightid(CURRENT_DATE);
     </sect3>
    </sect2>
 
+   <sect2 id="plpgsql-statements-returning-procedure">
+    <title>Returning From a Procedure</title>
+
+    <para>
+     A procedure does not have a return value.  A procedure can therefore end
+     without a <command>RETURN</command> statement.  If
+     a <command>RETURN</command> statement is desired to exit the code early,
+     then <symbol>NULL</symbol> must be returned.  Returning any other value
+     will result in an error.
+    </para>
+   </sect2>
+
    <sect2 id="plpgsql-conditionals">
     <title>Conditionals</title>
 
@@ -5244,7 +5257,7 @@ show errors;
     <para>
      Here is how this function would end up in <productname>PostgreSQL</productname>:
 <programlisting>
-CREATE OR REPLACE FUNCTION cs_update_referrer_type_proc() RETURNS void AS $func$
+CREATE OR REPLACE PROCEDURE cs_update_referrer_type_proc() AS $func$
 DECLARE
     referrer_keys CURSOR IS
         SELECT * FROM cs_referrer_keys
index ec5f671632da008ce66562979161769cdc334fe5..0dbeee1fa2e08aed687d7404bee7778a35ebdefb 100644 (file)
@@ -207,7 +207,11 @@ $$ LANGUAGE plpythonu;
    <literal>yield</literal> (in case of a result-set statement).  If
    you do not provide a return value, Python returns the default
    <symbol>None</symbol>. <application>PL/Python</application> translates
-   Python's <symbol>None</symbol> into the SQL null value.
+   Python's <symbol>None</symbol> into the SQL null value.  In a procedure,
+   the result from the Python code must be <symbol>None</symbol> (typically
+   achieved by ending the procedure without a <literal>return</literal>
+   statement or by using a <literal>return</literal> statement without
+   argument); otherwise, an error will be raised.
   </para>
 
   <para>
index 0646a8ba0baee36a8be3b804a8f8757d04703ce7..8018783b0a074228fc7fbcb1ac6d884a99617e85 100644 (file)
@@ -97,7 +97,8 @@ $$ LANGUAGE pltcl;
      Tcl script as variables named <literal>1</literal>
      ... <literal><replaceable>n</replaceable></literal>.  The result is
      returned from the Tcl code in the usual way, with
-     a <literal>return</literal> statement.
+     a <literal>return</literal> statement.  In a procedure, the return value
+     from the Tcl code is ignored.
     </para>
 
     <para>
index 01acc2ef9dad1986af16c7b4e46afbeb22f4c6c8..22e6893211575e70799454a3b9802c751e622dde 100644 (file)
@@ -26,8 +26,10 @@ Complete list of usable sgml source files in this directory.
 <!ENTITY alterOperatorClass SYSTEM "alter_opclass.sgml">
 <!ENTITY alterOperatorFamily SYSTEM "alter_opfamily.sgml">
 <!ENTITY alterPolicy        SYSTEM "alter_policy.sgml">
+<!ENTITY alterProcedure     SYSTEM "alter_procedure.sgml">
 <!ENTITY alterPublication   SYSTEM "alter_publication.sgml">
 <!ENTITY alterRole          SYSTEM "alter_role.sgml">
+<!ENTITY alterRoutine       SYSTEM "alter_routine.sgml">
 <!ENTITY alterRule          SYSTEM "alter_rule.sgml">
 <!ENTITY alterSchema        SYSTEM "alter_schema.sgml">
 <!ENTITY alterServer        SYSTEM "alter_server.sgml">
@@ -48,6 +50,7 @@ Complete list of usable sgml source files in this directory.
 <!ENTITY alterView          SYSTEM "alter_view.sgml">
 <!ENTITY analyze            SYSTEM "analyze.sgml">
 <!ENTITY begin              SYSTEM "begin.sgml">
+<!ENTITY call               SYSTEM "call.sgml">
 <!ENTITY checkpoint         SYSTEM "checkpoint.sgml">
 <!ENTITY close              SYSTEM "close.sgml">
 <!ENTITY cluster            SYSTEM "cluster.sgml">
@@ -75,6 +78,7 @@ Complete list of usable sgml source files in this directory.
 <!ENTITY createOperatorClass SYSTEM "create_opclass.sgml">
 <!ENTITY createOperatorFamily SYSTEM "create_opfamily.sgml">
 <!ENTITY createPolicy       SYSTEM "create_policy.sgml">
+<!ENTITY createProcedure    SYSTEM "create_procedure.sgml">
 <!ENTITY createPublication  SYSTEM "create_publication.sgml">
 <!ENTITY createRole         SYSTEM "create_role.sgml">
 <!ENTITY createRule         SYSTEM "create_rule.sgml">
@@ -122,8 +126,10 @@ Complete list of usable sgml source files in this directory.
 <!ENTITY dropOperatorFamily  SYSTEM "drop_opfamily.sgml">
 <!ENTITY dropOwned          SYSTEM "drop_owned.sgml">
 <!ENTITY dropPolicy         SYSTEM "drop_policy.sgml">
+<!ENTITY dropProcedure      SYSTEM "drop_procedure.sgml">
 <!ENTITY dropPublication    SYSTEM "drop_publication.sgml">
 <!ENTITY dropRole           SYSTEM "drop_role.sgml">
+<!ENTITY dropRoutine        SYSTEM "drop_routine.sgml">
 <!ENTITY dropRule           SYSTEM "drop_rule.sgml">
 <!ENTITY dropSchema         SYSTEM "drop_schema.sgml">
 <!ENTITY dropSequence       SYSTEM "drop_sequence.sgml">
index ab2c35b4dd010c6e85a679a6acb37cf107255d89..0c09f1db5cd11e061d956772a6e0891d13ee8d45 100644 (file)
@@ -39,7 +39,7 @@ GRANT { { USAGE | SELECT | UPDATE }
     TO { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
 
 GRANT { EXECUTE | ALL [ PRIVILEGES ] }
-    ON FUNCTIONS
+    ON { FUNCTIONS | ROUTINES }
     TO { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
 
 GRANT { USAGE | ALL [ PRIVILEGES ] }
@@ -66,7 +66,7 @@ REVOKE [ GRANT OPTION FOR ]
 
 REVOKE [ GRANT OPTION FOR ]
     { EXECUTE | ALL [ PRIVILEGES ] }
-    ON FUNCTIONS
+    ON { FUNCTIONS | ROUTINES }
     FROM { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...]
     [ CASCADE | RESTRICT ]
 
@@ -93,7 +93,13 @@ REVOKE [ GRANT OPTION FOR ]
    affect privileges assigned to already-existing objects.)  Currently,
    only the privileges for schemas, tables (including views and foreign
    tables), sequences, functions, and types (including domains) can be
-   altered.
+   altered.  For this command, functions include aggregates and procedures.
+   The words <literal>FUNCTIONS</literal> and <literal>ROUTINES</literal> are
+   equivalent in this command.  (<literal>ROUTINES</literal> is preferred
+   going forward as the standard term for functions and procedures taken
+   together.  In earlier PostgreSQL releases, only the
+   word <literal>FUNCTIONS</literal> was allowed.  It is not possible to set
+   default privileges for functions and procedures separately.)
   </para>
 
   <para>
index e54925507e11b2114b9eb07e40949974592d3f94..a2d405d6cdfb58d3b65e37ce72a13b23cc8a31fb 100644 (file)
@@ -45,6 +45,8 @@ ALTER EXTENSION <replaceable class="parameter">name</replaceable> DROP <replacea
   OPERATOR CLASS <replaceable class="parameter">object_name</replaceable> USING <replaceable class="parameter">index_method</replaceable> |
   OPERATOR FAMILY <replaceable class="parameter">object_name</replaceable> USING <replaceable class="parameter">index_method</replaceable> |
   [ PROCEDURAL ] LANGUAGE <replaceable class="parameter">object_name</replaceable> |
+  PROCEDURE <replaceable class="parameter">procedure_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] |
+  ROUTINE <replaceable class="parameter">routine_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] |
   SCHEMA <replaceable class="parameter">object_name</replaceable> |
   SEQUENCE <replaceable class="parameter">object_name</replaceable> |
   SERVER <replaceable class="parameter">object_name</replaceable> |
@@ -170,12 +172,14 @@ ALTER EXTENSION <replaceable class="parameter">name</replaceable> DROP <replacea
      <term><replaceable class="parameter">aggregate_name</replaceable></term>
      <term><replaceable class="parameter">function_name</replaceable></term>
      <term><replaceable class="parameter">operator_name</replaceable></term>
+     <term><replaceable class="parameter">procedure_name</replaceable></term>
+     <term><replaceable class="parameter">routine_name</replaceable></term>
      <listitem>
       <para>
        The name of an object to be added to or removed from the extension.
        Names of tables,
        aggregates, domains, foreign tables, functions, operators,
-       operator classes, operator families, sequences, text search objects,
+       operator classes, operator families, procedures, routines, sequences, text search objects,
        types, and views can be schema-qualified.
       </para>
      </listitem>
@@ -204,7 +208,7 @@ ALTER EXTENSION <replaceable class="parameter">name</replaceable> DROP <replacea
 
      <listitem>
       <para>
-       The mode of a function or aggregate
+       The mode of a function, procedure, or aggregate
        argument: <literal>IN</literal>, <literal>OUT</literal>,
        <literal>INOUT</literal>, or <literal>VARIADIC</literal>.
        If omitted, the default is <literal>IN</literal>.
@@ -222,7 +226,7 @@ ALTER EXTENSION <replaceable class="parameter">name</replaceable> DROP <replacea
 
      <listitem>
       <para>
-       The name of a function or aggregate argument.
+       The name of a function, procedure, or aggregate argument.
        Note that <command>ALTER EXTENSION</command> does not actually pay
        any attention to argument names, since only the argument data
        types are needed to determine the function's identity.
@@ -235,7 +239,7 @@ ALTER EXTENSION <replaceable class="parameter">name</replaceable> DROP <replacea
 
      <listitem>
       <para>
-       The data type of a function or aggregate argument.
+       The data type of a function, procedure, or aggregate argument.
       </para>
      </listitem>
     </varlistentry>
index 196d2dde0c0a9f0292ad74e31c3558221228dbd7..d8747e074821f9a1d91debd210368de102f7659a 100644 (file)
@@ -359,6 +359,8 @@ ALTER FUNCTION check_password(text) RESET search_path;
   <simplelist type="inline">
    <member><xref linkend="sql-createfunction"/></member>
    <member><xref linkend="sql-dropfunction"/></member>
+   <member><xref linkend="sql-alterprocedure"/></member>
+   <member><xref linkend="sql-alterroutine"/></member>
   </simplelist>
  </refsect1>
 </refentry>
diff --git a/doc/src/sgml/ref/alter_procedure.sgml b/doc/src/sgml/ref/alter_procedure.sgml
new file mode 100644 (file)
index 0000000..dae8007
--- /dev/null
@@ -0,0 +1,281 @@
+<!--
+doc/src/sgml/ref/alter_procedure.sgml
+PostgreSQL documentation
+-->
+
+<refentry id="sql-alterprocedure">
+ <indexterm zone="sql-alterprocedure">
+  <primary>ALTER PROCEDURE</primary>
+ </indexterm>
+
+ <refmeta>
+  <refentrytitle>ALTER PROCEDURE</refentrytitle>
+  <manvolnum>7</manvolnum>
+  <refmiscinfo>SQL - Language Statements</refmiscinfo>
+ </refmeta>
+
+ <refnamediv>
+  <refname>ALTER PROCEDURE</refname>
+  <refpurpose>change the definition of a procedure</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+ALTER PROCEDURE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ]
+    <replaceable class="parameter">action</replaceable> [ ... ] [ RESTRICT ]
+ALTER PROCEDURE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ]
+    RENAME TO <replaceable>new_name</replaceable>
+ALTER PROCEDURE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ]
+    OWNER TO { <replaceable>new_owner</replaceable> | CURRENT_USER | SESSION_USER }
+ALTER PROCEDURE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ]
+    SET SCHEMA <replaceable>new_schema</replaceable>
+ALTER PROCEDURE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ]
+    DEPENDS ON EXTENSION <replaceable>extension_name</replaceable>
+
+<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
+
+    [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
+    SET <replaceable class="parameter">configuration_parameter</replaceable> { TO | = } { <replaceable class="parameter">value</replaceable> | DEFAULT }
+    SET <replaceable class="parameter">configuration_parameter</replaceable> FROM CURRENT
+    RESET <replaceable class="parameter">configuration_parameter</replaceable>
+    RESET ALL
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <command>ALTER PROCEDURE</command> changes the definition of a
+   procedure.
+  </para>
+
+  <para>
+   You must own the procedure to use <command>ALTER PROCEDURE</command>.
+   To change a procedure's schema, you must also have <literal>CREATE</literal>
+   privilege on the new schema.
+   To alter the owner, you must also be a direct or indirect member of the new
+   owning role, and that role must have <literal>CREATE</literal> privilege on
+   the procedure's schema.  (These restrictions enforce that altering the owner
+   doesn't do anything you couldn't do by dropping and recreating the procedure.
+   However, a superuser can alter ownership of any procedure anyway.)
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term><replaceable class="parameter">name</replaceable></term>
+    <listitem>
+     <para>
+      The name (optionally schema-qualified) of an existing procedure.  If no
+      argument list is specified, the name must be unique in its schema.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><replaceable class="parameter">argmode</replaceable></term>
+
+    <listitem>
+     <para>
+      The mode of an argument: <literal>IN</literal>  or <literal>VARIADIC</literal>.
+      If omitted, the default is <literal>IN</literal>.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><replaceable class="parameter">argname</replaceable></term>
+
+    <listitem>
+     <para>
+      The name of an argument.
+      Note that <command>ALTER PROCEDURE</command> does not actually pay
+      any attention to argument names, since only the argument data
+      types are needed to determine the procedure's identity.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><replaceable class="parameter">argtype</replaceable></term>
+
+    <listitem>
+     <para>
+      The data type(s) of the procedure's arguments (optionally
+      schema-qualified), if any.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><replaceable class="parameter">new_name</replaceable></term>
+    <listitem>
+     <para>
+      The new name of the procedure.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><replaceable class="parameter">new_owner</replaceable></term>
+    <listitem>
+     <para>
+      The new owner of the procedure.  Note that if the procedure is
+      marked <literal>SECURITY DEFINER</literal>, it will subsequently
+      execute as the new owner.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><replaceable class="parameter">new_schema</replaceable></term>
+    <listitem>
+     <para>
+      The new schema for the procedure.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><replaceable class="parameter">extension_name</replaceable></term>
+    <listitem>
+     <para>
+      The name of the extension that the procedure is to depend on.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal><optional> EXTERNAL </optional> SECURITY INVOKER</literal></term>
+    <term><literal><optional> EXTERNAL </optional> SECURITY DEFINER</literal></term>
+
+    <listitem>
+     <para>
+      Change whether the procedure is a security definer or not. The
+      key word <literal>EXTERNAL</literal> is ignored for SQL
+      conformance. See <xref linkend="sql-createprocedure"/> for more information about
+      this capability.
+     </para>
+    </listitem>
+   </varlistentry>
+
+     <varlistentry>
+      <term><replaceable>configuration_parameter</replaceable></term>
+      <term><replaceable>value</replaceable></term>
+      <listitem>
+       <para>
+        Add or change the assignment to be made to a configuration parameter
+        when the procedure is called.  If
+        <replaceable>value</replaceable> is <literal>DEFAULT</literal>
+        or, equivalently, <literal>RESET</literal> is used, the procedure-local
+        setting is removed, so that the procedure executes with the value
+        present in its environment.  Use <literal>RESET
+        ALL</literal> to clear all procedure-local settings.
+        <literal>SET FROM CURRENT</literal> saves the value of the parameter that
+        is current when <command>ALTER PROCEDURE</command> is executed as the value
+        to be applied when the procedure is entered.
+       </para>
+
+       <para>
+        See <xref linkend="sql-set"/> and
+        <xref linkend="runtime-config"/>
+        for more information about allowed parameter names and values.
+       </para>
+      </listitem>
+     </varlistentry>
+
+   <varlistentry>
+    <term><literal>RESTRICT</literal></term>
+
+    <listitem>
+     <para>
+      Ignored for conformance with the SQL standard.
+     </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+ </refsect1>
+
+ <refsect1>
+  <title>Examples</title>
+
+  <para>
+   To rename the procedure <literal>insert_data</literal> with two arguments
+   of type <type>integer</type> to <literal>insert_record</literal>:
+<programlisting>
+ALTER PROCEDURE insert_data(integer, integer) RENAME TO insert_record;
+</programlisting>
+  </para>
+
+  <para>
+   To change the owner of the procedure <literal>insert_data</literal> with
+   two arguments of type <type>integer</type> to <literal>joe</literal>:
+<programlisting>
+ALTER PROCEDURE insert_data(integer, integer) OWNER TO joe;
+</programlisting>
+  </para>
+
+  <para>
+   To change the schema of the procedure <literal>insert_data</literal> with
+   two arguments of type <type>integer</type>
+   to <literal>accounting</literal>:
+<programlisting>
+ALTER PROCEDURE insert_data(integer, integer) SET SCHEMA accounting;
+</programlisting>
+  </para>
+
+  <para>
+   To mark the procedure <literal>insert_data(integer, integer)</literal> as
+   being dependent on the extension <literal>myext</literal>:
+<programlisting>
+ALTER PROCEDURE insert_data(integer, integer) DEPENDS ON EXTENSION myext;
+</programlisting>
+  </para>
+
+  <para>
+   To adjust the search path that is automatically set for a procedure:
+<programlisting>
+ALTER PROCEDURE check_password(text) SET search_path = admin, pg_temp;
+</programlisting>
+  </para>
+
+  <para>
+   To disable automatic setting of <varname>search_path</varname> for a procedure:
+<programlisting>
+ALTER PROCEDURE check_password(text) RESET search_path;
+</programlisting>
+   The procedure will now execute with whatever search path is used by its
+   caller.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>Compatibility</title>
+
+  <para>
+   This statement is partially compatible with the <command>ALTER
+   PROCEDURE</command> statement in the SQL standard. The standard allows more
+   properties of a procedure to be modified, but does not provide the
+   ability to rename a procedure, make a procedure a security definer,
+   attach configuration parameter values to a procedure,
+   or change the owner, schema, or volatility of a procedure. The standard also
+   requires the <literal>RESTRICT</literal> key word, which is optional in
+   <productname>PostgreSQL</productname>.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>See Also</title>
+
+  <simplelist type="inline">
+   <member><xref linkend="sql-createprocedure"/></member>
+   <member><xref linkend="sql-dropprocedure"/></member>
+   <member><xref linkend="sql-alterfunction"/></member>
+   <member><xref linkend="sql-alterroutine"/></member>
+  </simplelist>
+ </refsect1>
+</refentry>
diff --git a/doc/src/sgml/ref/alter_routine.sgml b/doc/src/sgml/ref/alter_routine.sgml
new file mode 100644 (file)
index 0000000..d169969
--- /dev/null
@@ -0,0 +1,102 @@
+<!--
+doc/src/sgml/ref/alter_routine.sgml
+PostgreSQL documentation
+-->
+
+<refentry id="sql-alterroutine">
+ <indexterm zone="sql-alterroutine">
+  <primary>ALTER ROUTINE</primary>
+ </indexterm>
+
+ <refmeta>
+  <refentrytitle>ALTER ROUTINE</refentrytitle>
+  <manvolnum>7</manvolnum>
+  <refmiscinfo>SQL - Language Statements</refmiscinfo>
+ </refmeta>
+
+ <refnamediv>
+  <refname>ALTER ROUTINE</refname>
+  <refpurpose>change the definition of a routine</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+ALTER ROUTINE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ]
+    <replaceable class="parameter">action</replaceable> [ ... ] [ RESTRICT ]
+ALTER ROUTINE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ]
+    RENAME TO <replaceable>new_name</replaceable>
+ALTER ROUTINE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ]
+    OWNER TO { <replaceable>new_owner</replaceable> | CURRENT_USER | SESSION_USER }
+ALTER ROUTINE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ]
+    SET SCHEMA <replaceable>new_schema</replaceable>
+ALTER ROUTINE <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ]
+    DEPENDS ON EXTENSION <replaceable>extension_name</replaceable>
+
+<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
+
+    IMMUTABLE | STABLE | VOLATILE | [ NOT ] LEAKPROOF
+    [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
+    PARALLEL { UNSAFE | RESTRICTED | SAFE }
+    COST <replaceable class="parameter">execution_cost</replaceable>
+    ROWS <replaceable class="parameter">result_rows</replaceable>
+    SET <replaceable class="parameter">configuration_parameter</replaceable> { TO | = } { <replaceable class="parameter">value</replaceable> | DEFAULT }
+    SET <replaceable class="parameter">configuration_parameter</replaceable> FROM CURRENT
+    RESET <replaceable class="parameter">configuration_parameter</replaceable>
+    RESET ALL
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <command>ALTER ROUTINE</command> changes the definition of a routine, which
+   can be an aggregate function, a normal function, or a procedure.  See
+   under <xref linkend="sql-alteraggregate"/>, <xref linkend="sql-alterfunction"/>,
+   and <xref linkend="sql-alterprocedure"/> for the description of the
+   parameters, more examples, and further details.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>Examples</title>
+
+  <para>
+   To rename the routine <literal>foo</literal> for type
+   <type>integer</type> to <literal>foobar</literal>:
+<programlisting>
+ALTER ROUTINE foo(integer) RENAME TO foobar;
+</programlisting>
+   This command will work independent of whether <literal>foo</literal> is an
+   aggregate, function, or procedure.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>Compatibility</title>
+
+  <para>
+   This statement is partially compatible with the <command>ALTER
+   ROUTINE</command> statement in the SQL standard.  See
+   under <xref linkend="sql-alterfunction"/>
+   and <xref linkend="sql-alterprocedure"/> for more details.  Allowing
+   routine names to refer to aggregate functions is
+   a <productname>PostgreSQL</productname> extension.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>See Also</title>
+
+  <simplelist type="inline">
+   <member><xref linkend="sql-alteraggregate"/></member>
+   <member><xref linkend="sql-alterfunction"/></member>
+   <member><xref linkend="sql-alterprocedure"/></member>
+   <member><xref linkend="sql-droproutine"/></member>
+  </simplelist>
+
+  <para>
+   Note that there is no <literal>CREATE ROUTINE</literal> command.
+  </para>
+ </refsect1>
+</refentry>
diff --git a/doc/src/sgml/ref/call.sgml b/doc/src/sgml/ref/call.sgml
new file mode 100644 (file)
index 0000000..2741d8d
--- /dev/null
@@ -0,0 +1,97 @@
+<!--
+doc/src/sgml/ref/call.sgml
+PostgreSQL documentation
+-->
+
+<refentry id="sql-call">
+ <indexterm zone="sql-call">
+  <primary>CALL</primary>
+ </indexterm>
+
+ <refmeta>
+  <refentrytitle>CALL</refentrytitle>
+  <manvolnum>7</manvolnum>
+  <refmiscinfo>SQL - Language Statements</refmiscinfo>
+ </refmeta>
+
+ <refnamediv>
+  <refname>CALL</refname>
+  <refpurpose>invoke a procedure</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+CALL <replaceable class="parameter">name</replaceable> ( [ <replaceable class="parameter">argument</replaceable> ] [ , ...] )
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <command>CALL</command> executes a procedure.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>Parameters</title>
+
+  <variablelist>
+   <varlistentry>
+    <term><replaceable class="parameter">name</replaceable></term>
+    <listitem>
+     <para>
+      The name (optionally schema-qualified) of the procedure.
+     </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term><replaceable class="parameter">argument</replaceable></term>
+    <listitem>
+     <para>
+      An argument for the procedure call.
+      See <xref linkend="sql-syntax-calling-funcs"/> for the full details on
+      function and procedure call syntax, including use of named parameters.
+     </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+ </refsect1>
+
+ <refsect1>
+  <title>Notes</title>
+
+  <para>
+   The user must have <literal>EXECUTE</literal> privilege on the procedure in
+   order to be allowed to invoke it.
+  </para>
+
+  <para>
+   To call a function (not a procedure), use <command>SELECT</command> instead.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>Examples</title>
+<programlisting>
+CALL do_db_maintenance();
+</programlisting>
+ </refsect1>
+
+ <refsect1>
+  <title>Compatibility</title>
+
+  <para>
+   <command>CALL</command> conforms to the SQL standard.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>See Also</title>
+
+  <simplelist type="inline">
+   <member><xref linkend="sql-createprocedure"/></member>
+  </simplelist>
+ </refsect1>
+</refentry>
index 7d66c1a34ca97cefd7a9880bc7d785047526a322..965c5a40ad72a54886043b5e398d67b890e53f94 100644 (file)
@@ -46,8 +46,10 @@ COMMENT ON
   OPERATOR FAMILY <replaceable class="parameter">object_name</replaceable> USING <replaceable class="parameter">index_method</replaceable> |
   POLICY <replaceable class="parameter">policy_name</replaceable> ON <replaceable class="parameter">table_name</replaceable> |
   [ PROCEDURAL ] LANGUAGE <replaceable class="parameter">object_name</replaceable> |
+  PROCEDURE <replaceable class="parameter">procedure_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] |
   PUBLICATION <replaceable class="parameter">object_name</replaceable> |
   ROLE <replaceable class="parameter">object_name</replaceable> |
+  ROUTINE <replaceable class="parameter">routine_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] |
   RULE <replaceable class="parameter">rule_name</replaceable> ON <replaceable class="parameter">table_name</replaceable> |
   SCHEMA <replaceable class="parameter">object_name</replaceable> |
   SEQUENCE <replaceable class="parameter">object_name</replaceable> |
@@ -121,13 +123,15 @@ COMMENT ON
     <term><replaceable class="parameter">function_name</replaceable></term>
     <term><replaceable class="parameter">operator_name</replaceable></term>
     <term><replaceable class="parameter">policy_name</replaceable></term>
+    <term><replaceable class="parameter">procedure_name</replaceable></term>
+    <term><replaceable class="parameter">routine_name</replaceable></term>
     <term><replaceable class="parameter">rule_name</replaceable></term>
     <term><replaceable class="parameter">trigger_name</replaceable></term>
     <listitem>
      <para>
       The name of the object to be commented.  Names of tables,
       aggregates, collations, conversions, domains, foreign tables, functions,
-      indexes, operators, operator classes, operator families, sequences,
+      indexes, operators, operator classes, operator families, procedures, routines, sequences,
       statistics, text search objects, types, and views can be
       schema-qualified. When commenting on a column,
       <replaceable class="parameter">relation_name</replaceable> must refer
@@ -170,7 +174,7 @@ COMMENT ON
     <term><replaceable class="parameter">argmode</replaceable></term>
     <listitem>
      <para>
-      The mode of a function or aggregate
+      The mode of a function, procedure, or aggregate
       argument: <literal>IN</literal>, <literal>OUT</literal>,
       <literal>INOUT</literal>, or <literal>VARIADIC</literal>.
       If omitted, the default is <literal>IN</literal>.
@@ -187,7 +191,7 @@ COMMENT ON
     <term><replaceable class="parameter">argname</replaceable></term>
     <listitem>
      <para>
-      The name of a function or aggregate argument.
+      The name of a function, procedure, or aggregate argument.
       Note that <command>COMMENT</command> does not actually pay
       any attention to argument names, since only the argument data
       types are needed to determine the function's identity.
@@ -199,7 +203,7 @@ COMMENT ON
     <term><replaceable class="parameter">argtype</replaceable></term>
     <listitem>
      <para>
-      The data type of a function or aggregate argument.
+      The data type of a function, procedure, or aggregate argument.
      </para>
     </listitem>
    </varlistentry>
@@ -325,6 +329,7 @@ COMMENT ON OPERATOR - (NONE, integer) IS 'Unary minus';
 COMMENT ON OPERATOR CLASS int4ops USING btree IS '4 byte integer operators for btrees';
 COMMENT ON OPERATOR FAMILY integer_ops USING btree IS 'all integer operators for btrees';
 COMMENT ON POLICY my_policy ON mytable IS 'Filter rows by users';
+COMMENT ON PROCEDURE my_proc (integer, integer) IS 'Runs a report';
 COMMENT ON ROLE my_role IS 'Administration group for finance tables';
 COMMENT ON RULE my_rule ON my_table IS 'Logs updates of employee records';
 COMMENT ON SCHEMA my_schema IS 'Departmental data';
index 75331165fef95699c3d0427b715efdda56845d26..fd229d1193733194c9c1191be7b3faad5dfb0e9c 100644 (file)
@@ -55,9 +55,9 @@ CREATE [ OR REPLACE ] FUNCTION
   <para>
    If a schema name is included, then the function is created in the
    specified schema.  Otherwise it is created in the current schema.
-   The name of the new function must not match any existing function
+   The name of the new function must not match any existing function or procedure
    with the same input argument types in the same schema.  However,
-   functions of different argument types can share a name (this is
+   functions and procedures of different argument types can share a name (this is
    called <firstterm>overloading</firstterm>).
   </para>
 
@@ -450,7 +450,7 @@ CREATE [ OR REPLACE ] FUNCTION
    </varlistentry>
 
     <varlistentry>
-     <term><replaceable class="parameter">execution_cost</replaceable></term>
+     <term><literal>COST</literal> <replaceable class="parameter">execution_cost</replaceable></term>
 
      <listitem>
       <para>
@@ -466,7 +466,7 @@ CREATE [ OR REPLACE ] FUNCTION
     </varlistentry>
 
     <varlistentry>
-     <term><replaceable class="parameter">result_rows</replaceable></term>
+     <term><literal>ROWS</literal> <replaceable class="parameter">result_rows</replaceable></term>
 
      <listitem>
       <para>
@@ -818,7 +818,7 @@ COMMIT;
   <title>Compatibility</title>
 
   <para>
-   A <command>CREATE FUNCTION</command> command is defined in SQL:1999 and later.
+   A <command>CREATE FUNCTION</command> command is defined in the SQL standard.
    The <productname>PostgreSQL</productname> version is similar but
    not fully compatible.  The attributes are not portable, neither are the
    different available languages.
diff --git a/doc/src/sgml/ref/create_procedure.sgml b/doc/src/sgml/ref/create_procedure.sgml
new file mode 100644 (file)
index 0000000..d712043
--- /dev/null
@@ -0,0 +1,341 @@
+<!--
+doc/src/sgml/ref/create_procedure.sgml
+-->
+
+<refentry id="sql-createprocedure">
+ <indexterm zone="sql-createprocedure">
+  <primary>CREATE PROCEDURE</primary>
+ </indexterm>
+
+ <refmeta>
+  <refentrytitle>CREATE PROCEDURE</refentrytitle>
+  <manvolnum>7</manvolnum>
+  <refmiscinfo>SQL - Language Statements</refmiscinfo>
+ </refmeta>
+
+ <refnamediv>
+  <refname>CREATE PROCEDURE</refname>
+  <refpurpose>define a new procedure</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+CREATE [ OR REPLACE ] PROCEDURE
+    <replaceable class="parameter">name</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [ { DEFAULT | = } <replaceable class="parameter">default_expr</replaceable> ] [, ...] ] )
+  { LANGUAGE <replaceable class="parameter">lang_name</replaceable>
+    | TRANSFORM { FOR TYPE <replaceable class="parameter">type_name</replaceable> } [, ... ]
+    | [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
+    | SET <replaceable class="parameter">configuration_parameter</replaceable> { TO <replaceable class="parameter">value</replaceable> | = <replaceable class="parameter">value</replaceable> | FROM CURRENT }
+    | AS '<replaceable class="parameter">definition</replaceable>'
+    | AS '<replaceable class="parameter">obj_file</replaceable>', '<replaceable class="parameter">link_symbol</replaceable>'
+  } ...
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1 id="sql-createprocedure-description">
+  <title>Description</title>
+
+  <para>
+   <command>CREATE PROCEDURE</command> defines a new procedure.
+   <command>CREATE OR REPLACE PROCEDURE</command> will either create a
+   new procedure, or replace an existing definition.
+   To be able to define a procedure, the user must have the
+   <literal>USAGE</literal> privilege on the language.
+  </para>
+
+  <para>
+   If a schema name is included, then the procedure is created in the
+   specified schema.  Otherwise it is created in the current schema.
+   The name of the new procedure must not match any existing procedure or function
+   with the same input argument types in the same schema.  However,
+   procedures and functions of different argument types can share a name (this is
+   called <firstterm>overloading</firstterm>).
+  </para>
+
+  <para>
+   To replace the current definition of an existing procedure, use
+   <command>CREATE OR REPLACE PROCEDURE</command>.  It is not possible
+   to change the name or argument types of a procedure this way (if you
+   tried, you would actually be creating a new, distinct procedure).
+  </para>
+
+  <para>
+   When <command>CREATE OR REPLACE PROCEDURE</command> is used to replace an
+   existing procedure, the ownership and permissions of the procedure
+   do not change.  All other procedure properties are assigned the
+   values specified or implied in the command.  You must own the procedure
+   to replace it (this includes being a member of the owning role).
+  </para>
+
+  <para>
+   The user that creates the procedure becomes the owner of the procedure.
+  </para>
+
+  <para>
+   To be able to create a procedure, you must have <literal>USAGE</literal>
+   privilege on the argument types.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>Parameters</title>
+
+   <variablelist>
+    <varlistentry>
+     <term><replaceable class="parameter">name</replaceable></term>
+
+     <listitem>
+      <para>
+       The name (optionally schema-qualified) of the procedure to create.
+      </para>
+     </listitem>
+    </varlistentry>
+
+    <varlistentry>
+     <term><replaceable class="parameter">argmode</replaceable></term>
+
+     <listitem>
+      <para>
+       The mode of an argument: <literal>IN</literal> or <literal>VARIADIC</literal>.
+       If omitted, the default is <literal>IN</literal>.
+      </para>
+     </listitem>
+    </varlistentry>
+
+    <varlistentry>
+     <term><replaceable class="parameter">argname</replaceable></term>
+
+     <listitem>
+      <para>
+       The name of an argument.
+      </para>
+     </listitem>
+    </varlistentry>
+
+    <varlistentry>
+     <term><replaceable class="parameter">argtype</replaceable></term>
+
+     <listitem>
+      <para>
+       The data type(s) of the procedure's arguments (optionally
+       schema-qualified), if any. The argument types can be base, composite,
+       or domain types, or can reference the type of a table column.
+      </para>
+      <para>
+       Depending on the implementation language it might also be allowed
+       to specify <quote>pseudo-types</quote> such as <type>cstring</type>.
+       Pseudo-types indicate that the actual argument type is either
+       incompletely specified, or outside the set of ordinary SQL data types.
+      </para>
+      <para>
+       The type of a column is referenced by writing
+       <literal><replaceable
+       class="parameter">table_name</replaceable>.<replaceable
+       class="parameter">column_name</replaceable>%TYPE</literal>.
+       Using this feature can sometimes help make a procedure independent of
+       changes to the definition of a table.
+      </para>
+     </listitem>
+    </varlistentry>
+
+    <varlistentry>
+     <term><replaceable class="parameter">default_expr</replaceable></term>
+
+     <listitem>
+      <para>
+       An expression to be used as default value if the parameter is
+       not specified.  The expression has to be coercible to the
+       argument type of the parameter.
+       All input parameters following a
+       parameter with a default value must have default values as well.
+      </para>
+     </listitem>
+    </varlistentry>
+
+    <varlistentry>
+     <term><replaceable class="parameter">lang_name</replaceable></term>
+
+     <listitem>
+      <para>
+       The name of the language that the procedure is implemented in.
+       It can be <literal>sql</literal>, <literal>c</literal>,
+       <literal>internal</literal>, or the name of a user-defined
+       procedural language, e.g. <literal>plpgsql</literal>.  Enclosing the
+       name in single quotes is deprecated and requires matching case.
+      </para>
+     </listitem>
+    </varlistentry>
+
+    <varlistentry>
+     <term><literal>TRANSFORM { FOR TYPE <replaceable class="parameter">type_name</replaceable> } [, ... ] }</literal></term>
+
+     <listitem>
+      <para>
+       Lists which transforms a call to the procedure should apply.  Transforms
+       convert between SQL types and language-specific data types;
+       see <xref linkend="sql-createtransform"/>.  Procedural language
+       implementations usually have hardcoded knowledge of the built-in types,
+       so those don't need to be listed here.  If a procedural language
+       implementation does not know how to handle a type and no transform is
+       supplied, it will fall back to a default behavior for converting data
+       types, but this depends on the implementation.
+      </para>
+     </listitem>
+    </varlistentry>
+
+   <varlistentry>
+    <term><literal><optional>EXTERNAL</optional> SECURITY INVOKER</literal></term>
+    <term><literal><optional>EXTERNAL</optional> SECURITY DEFINER</literal></term>
+
+    <listitem>
+     <para><literal>SECURITY INVOKER</literal> indicates that the procedure
+      is to be executed with the privileges of the user that calls it.
+      That is the default.  <literal>SECURITY DEFINER</literal>
+      specifies that the procedure is to be executed with the
+      privileges of the user that owns it.
+     </para>
+
+     <para>
+      The key word <literal>EXTERNAL</literal> is allowed for SQL
+      conformance, but it is optional since, unlike in SQL, this feature
+      applies to all procedures not only external ones.
+     </para>
+    </listitem>
+   </varlistentry>
+
+    <varlistentry>
+     <term><replaceable>configuration_parameter</replaceable></term>
+     <term><replaceable>value</replaceable></term>
+     <listitem>
+      <para>
+       The <literal>SET</literal> clause causes the specified configuration
+       parameter to be set to the specified value when the procedure is
+       entered, and then restored to its prior value when the procedure exits.
+       <literal>SET FROM CURRENT</literal> saves the value of the parameter that
+       is current when <command>CREATE PROCEDURE</command> is executed as the value
+       to be applied when the procedure is entered.
+      </para>
+
+      <para>
+       If a <literal>SET</literal> clause is attached to a procedure, then
+       the effects of a <command>SET LOCAL</command> command executed inside the
+       procedure for the same variable are restricted to the procedure: the
+       configuration parameter's prior value is still restored at procedure exit.
+       However, an ordinary
+       <command>SET</command> command (without <literal>LOCAL</literal>) overrides the
+       <literal>SET</literal> clause, much as it would do for a previous <command>SET
+       LOCAL</command> command: the effects of such a command will persist after
+       procedure exit, unless the current transaction is rolled back.
+      </para>
+
+      <para>
+       See <xref linkend="sql-set"/> and
+       <xref linkend="runtime-config"/>
+       for more information about allowed parameter names and values.
+      </para>
+     </listitem>
+    </varlistentry>
+
+    <varlistentry>
+     <term><replaceable class="parameter">definition</replaceable></term>
+
+     <listitem>
+      <para>
+       A string constant defining the procedure; the meaning depends on the
+       language.  It can be an internal procedure name, the path to an
+       object file, an SQL command, or text in a procedural language.
+      </para>
+
+      <para>
+       It is often helpful to use dollar quoting (see <xref
+       linkend="sql-syntax-dollar-quoting"/>) to write the procedure definition
+       string, rather than the normal single quote syntax.  Without dollar
+       quoting, any single quotes or backslashes in the procedure definition must
+       be escaped by doubling them.
+      </para>
+
+     </listitem>
+    </varlistentry>
+
+    <varlistentry>
+     <term><literal><replaceable class="parameter">obj_file</replaceable>, <replaceable class="parameter">link_symbol</replaceable></literal></term>
+
+     <listitem>
+      <para>
+       This form of the <literal>AS</literal> clause is used for
+       dynamically loadable C language procedures when the procedure name
+       in the C language source code is not the same as the name of
+       the SQL procedure. The string <replaceable
+       class="parameter">obj_file</replaceable> is the name of the shared
+       library file containing the compiled C procedure, and is interpreted
+       as for the <xref linkend="sql-load"/> command.  The string
+       <replaceable class="parameter">link_symbol</replaceable> is the
+       procedure's link symbol, that is, the name of the procedure in the C
+       language source code.  If the link symbol is omitted, it is assumed
+       to be the same as the name of the SQL procedure being defined.
+      </para>
+
+      <para>
+       When repeated <command>CREATE PROCEDURE</command> calls refer to
+       the same object file, the file is only loaded once per session.
+       To unload and
+       reload the file (perhaps during development), start a new session.
+      </para>
+
+     </listitem>
+    </varlistentry>
+   </variablelist>
+ </refsect1>
+
+ <refsect1 id="sql-createprocedure-notes">
+  <title>Notes</title>
+
+  <para>
+   See <xref linkend="sql-createfunction"/> for more details on function
+   creation that also apply to procedures.
+  </para>
+
+  <para>
+   Use <xref linkend="sql-call"/> to execute a procedure.
+  </para>
+ </refsect1>
+
+ <refsect1 id="sql-createprocedure-examples">
+  <title>Examples</title>
+
+<programlisting>
+CREATE PROCEDURE insert_data(a integer, b integer)
+LANGUAGE SQL
+AS $$
+INSERT INTO tbl VALUES (a);
+INSERT INTO tbl VALUES (b);
+$$;
+
+CALL insert_data(1, 2);
+</programlisting>
+ </refsect1>
+
+ <refsect1 id="sql-createprocedure-compat">
+  <title>Compatibility</title>
+
+  <para>
+   A <command>CREATE PROCEDURE</command> command is defined in the SQL
+   standard.  The <productname>PostgreSQL</productname> version is similar but
+   not fully compatible.  For details see
+   also <xref linkend="sql-createfunction"/>.
+  </para>
+ </refsect1>
+
+
+ <refsect1>
+  <title>See Also</title>
+
+  <simplelist type="inline">
+   <member><xref linkend="sql-alterprocedure"/></member>
+   <member><xref linkend="sql-dropprocedure"/></member>
+   <member><xref linkend="sql-call"/></member>
+   <member><xref linkend="sql-createfunction"/></member>
+  </simplelist>
+ </refsect1>
+
+</refentry>
index eda1a59c84653b78d99e6078dbb0228e16e4ca7d..127fdfe419770ed016dc8d28e2d1f1a3805f7c97 100644 (file)
@@ -185,6 +185,8 @@ DROP FUNCTION update_employee_salaries();
   <simplelist type="inline">
    <member><xref linkend="sql-createfunction"/></member>
    <member><xref linkend="sql-alterfunction"/></member>
+   <member><xref linkend="sql-dropprocedure"/></member>
+   <member><xref linkend="sql-droproutine"/></member>
   </simplelist>
  </refsect1>
 
diff --git a/doc/src/sgml/ref/drop_procedure.sgml b/doc/src/sgml/ref/drop_procedure.sgml
new file mode 100644 (file)
index 0000000..fef61b6
--- /dev/null
@@ -0,0 +1,162 @@
+<!--
+doc/src/sgml/ref/drop_procedure.sgml
+PostgreSQL documentation
+-->
+
+<refentry id="sql-dropprocedure">
+ <indexterm zone="sql-dropprocedure">
+  <primary>DROP PROCEDURE</primary>
+ </indexterm>
+
+ <refmeta>
+  <refentrytitle>DROP PROCEDURE</refentrytitle>
+  <manvolnum>7</manvolnum>
+  <refmiscinfo>SQL - Language Statements</refmiscinfo>
+ </refmeta>
+
+ <refnamediv>
+  <refname>DROP PROCEDURE</refname>
+  <refpurpose>remove a procedure</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+DROP PROCEDURE [ IF EXISTS ] <replaceable class="parameter">name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] [, ...]
+    [ CASCADE | RESTRICT ]
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <command>DROP PROCEDURE</command> removes the definition of an existing
+   procedure. To execute this command the user must be the
+   owner of the procedure. The argument types to the
+   procedure must be specified, since several different procedures
+   can exist with the same name and different argument lists.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>Parameters</title>
+
+  <variablelist>
+    <varlistentry>
+    <term><literal>IF EXISTS</literal></term>
+    <listitem>
+     <para>
+      Do not throw an error if the procedure does not exist. A notice is issued
+      in this case.
+     </para>
+    </listitem>
+   </varlistentry>
+
+  <varlistentry>
+    <term><replaceable class="parameter">name</replaceable></term>
+    <listitem>
+     <para>
+      The name (optionally schema-qualified) of an existing procedure.  If no
+      argument list is specified, the name must be unique in its schema.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><replaceable class="parameter">argmode</replaceable></term>
+
+    <listitem>
+     <para>
+      The mode of an argument: <literal>IN</literal> or <literal>VARIADIC</literal>.
+      If omitted, the default is <literal>IN</literal>.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><replaceable class="parameter">argname</replaceable></term>
+
+    <listitem>
+     <para>
+      The name of an argument.
+      Note that <command>DROP PROCEDURE</command> does not actually pay
+      any attention to argument names, since only the argument data
+      types are needed to determine the procedure's identity.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><replaceable class="parameter">argtype</replaceable></term>
+
+    <listitem>
+     <para>
+      The data type(s) of the procedure's arguments (optionally
+      schema-qualified), if any.
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>CASCADE</literal></term>
+    <listitem>
+     <para>
+      Automatically drop objects that depend on the procedure,
+      and in turn all objects that depend on those objects
+      (see <xref linkend="ddl-depend"/>).
+     </para>
+    </listitem>
+   </varlistentry>
+
+   <varlistentry>
+    <term><literal>RESTRICT</literal></term>
+    <listitem>
+     <para>
+      Refuse to drop the procedure if any objects depend on it.  This
+      is the default.
+     </para>
+    </listitem>
+   </varlistentry>
+  </variablelist>
+ </refsect1>
+
+ <refsect1 id="sql-dropprocedure-examples">
+  <title>Examples</title>
+
+<programlisting>
+DROP PROCEDURE do_db_maintenance();
+</programlisting>
+ </refsect1>
+
+ <refsect1 id="sql-dropprocedure-compatibility">
+  <title>Compatibility</title>
+
+  <para>
+   This command conforms to the SQL standard, with
+   these <productname>PostgreSQL</productname> extensions:
+   <itemizedlist>
+    <listitem>
+     <para>The standard only allows one procedure to be dropped per command.</para>
+    </listitem>
+    <listitem>
+     <para>The <literal>IF EXISTS</literal> option</para>
+    </listitem>
+    <listitem>
+     <para>The ability to specify argument modes and names</para>
+    </listitem>
+   </itemizedlist>
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>See Also</title>
+
+  <simplelist type="inline">
+   <member><xref linkend="sql-createprocedure"/></member>
+   <member><xref linkend="sql-alterprocedure"/></member>
+   <member><xref linkend="sql-dropfunction"/></member>
+   <member><xref linkend="sql-droproutine"/></member>
+  </simplelist>
+ </refsect1>
+
+</refentry>
diff --git a/doc/src/sgml/ref/drop_routine.sgml b/doc/src/sgml/ref/drop_routine.sgml
new file mode 100644 (file)
index 0000000..5cd1a0f
--- /dev/null
@@ -0,0 +1,94 @@
+<!--
+doc/src/sgml/ref/drop_routine.sgml
+PostgreSQL documentation
+-->
+
+<refentry id="sql-droproutine">
+ <indexterm zone="sql-droproutine">
+  <primary>DROP ROUTINE</primary>
+ </indexterm>
+
+ <refmeta>
+  <refentrytitle>DROP ROUTINE</refentrytitle>
+  <manvolnum>7</manvolnum>
+  <refmiscinfo>SQL - Language Statements</refmiscinfo>
+ </refmeta>
+
+ <refnamediv>
+  <refname>DROP ROUTINE</refname>
+  <refpurpose>remove a routine</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+DROP ROUTINE [ IF EXISTS ] <replaceable class="parameter">name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] [, ...]
+    [ CASCADE | RESTRICT ]
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <command>DROP ROUTINE</command> removes the definition of an existing
+   routine, which can be an aggregate function, a normal function, or a
+   procedure.  See
+   under <xref linkend="sql-dropaggregate"/>, <xref linkend="sql-dropfunction"/>,
+   and <xref linkend="sql-dropprocedure"/> for the description of the
+   parameters, more examples, and further details.
+  </para>
+ </refsect1>
+
+ <refsect1 id="sql-droproutine-examples">
+  <title>Examples</title>
+
+  <para>
+   To drop the routine <literal>foo</literal> for type
+   <type>integer</type>:
+<programlisting>
+DROP ROUTINE foo(integer);
+</programlisting>
+   This command will work independent of whether <literal>foo</literal> is an
+   aggregate, function, or procedure.
+  </para>
+ </refsect1>
+
+ <refsect1 id="sql-droproutine-compatibility">
+  <title>Compatibility</title>
+
+  <para>
+   This command conforms to the SQL standard, with
+   these <productname>PostgreSQL</productname> extensions:
+   <itemizedlist>
+    <listitem>
+     <para>The standard only allows one routine to be dropped per command.</para>
+    </listitem>
+    <listitem>
+     <para>The <literal>IF EXISTS</literal> option</para>
+    </listitem>
+    <listitem>
+     <para>The ability to specify argument modes and names</para>
+    </listitem>
+    <listitem>
+     <para>Aggregate functions are an extension.</para>
+    </listitem>
+   </itemizedlist>
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>See Also</title>
+
+  <simplelist type="inline">
+   <member><xref linkend="sql-dropaggregate"/></member>
+   <member><xref linkend="sql-dropfunction"/></member>
+   <member><xref linkend="sql-dropprocedure"/></member>
+   <member><xref linkend="sql-alterroutine"/></member>
+  </simplelist>
+
+  <para>
+   Note that there is no <literal>CREATE ROUTINE</literal> command.
+  </para>
+ </refsect1>
+
+</refentry>
index a5e895d09d7d800a23676f05ed667398a1744cfc..ff64c7a3bae65c3de3437ef2e8bef4af19bb8709 100644 (file)
@@ -55,8 +55,8 @@ GRANT { USAGE | ALL [ PRIVILEGES ] }
     TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ]
 
 GRANT { EXECUTE | ALL [ PRIVILEGES ] }
-    ON { FUNCTION <replaceable>function_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">arg_name</replaceable> ] <replaceable class="parameter">arg_type</replaceable> [, ...] ] ) ] [, ...]
-         | ALL FUNCTIONS IN SCHEMA <replaceable class="parameter">schema_name</replaceable> [, ...] }
+    ON { { FUNCTION | PROCEDURE | ROUTINE } <replaceable>routine_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">arg_name</replaceable> ] <replaceable class="parameter">arg_type</replaceable> [, ...] ] ) ] [, ...]
+         | ALL { FUNCTIONS | PROCEDURES | ROUTINES } IN SCHEMA <replaceable class="parameter">schema_name</replaceable> [, ...] }
     TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ]
 
 GRANT { USAGE | ALL [ PRIVILEGES ] }
@@ -96,7 +96,7 @@ GRANT <replaceable class="parameter">role_name</replaceable> [, ...] TO <replace
   <para>
    The <command>GRANT</command> command has two basic variants: one
    that grants privileges on a database object (table, column, view, foreign
-   table, sequence, database, foreign-data wrapper, foreign server, function,
+   table, sequence, database, foreign-data wrapper, foreign server, function, procedure,
    procedural language, schema, or tablespace), and one that grants
    membership in a role.  These variants are similar in many ways, but
    they are different enough to be described separately.
@@ -115,8 +115,11 @@ GRANT <replaceable class="parameter">role_name</replaceable> [, ...] TO <replace
   <para>
    There is also an option to grant privileges on all objects of the same
    type within one or more schemas.  This functionality is currently supported
-   only for tables, sequences, and functions (but note that <literal>ALL
-   TABLES</literal> is considered to include views and foreign tables).
+   only for tables, sequences, functions, and procedures.  <literal>ALL
+   TABLES</literal> also affects views and foreign tables, just like the
+   specific-object <command>GRANT</command> command.  <literal>ALL
+   FUNCTIONS</literal> also affects aggregate functions, but not procedures,
+   again just like the specific-object <command>GRANT</command> command.
   </para>
 
   <para>
@@ -169,7 +172,7 @@ GRANT <replaceable class="parameter">role_name</replaceable> [, ...] TO <replace
    granted to <literal>PUBLIC</literal> are as follows:
    <literal>CONNECT</literal> and <literal>TEMPORARY</literal> (create
    temporary tables) privileges for databases;
-   <literal>EXECUTE</literal> privilege for functions; and
+   <literal>EXECUTE</literal> privilege for functions and procedures; and
    <literal>USAGE</literal> privilege for languages and data types
    (including domains).
    The object owner can, of course, <command>REVOKE</command>
@@ -329,10 +332,12 @@ GRANT <replaceable class="parameter">role_name</replaceable> [, ...] TO <replace
      <term><literal>EXECUTE</literal></term>
      <listitem>
       <para>
-       Allows the use of the specified function and the use of any
-       operators that are implemented on top of the function.  This is
-       the only type of privilege that is applicable to functions.
-       (This syntax works for aggregate functions, as well.)
+       Allows the use of the specified function or procedure and the use of
+       any operators that are implemented on top of the function.  This is the
+       only type of privilege that is applicable to functions and procedures.
+       The <literal>FUNCTION</literal> syntax also works for aggregate
+       functions.  Alternatively, use <literal>ROUTINE</literal> to refer to a function,
+       aggregate function, or procedure regardless of what it is.
       </para>
      </listitem>
     </varlistentry>
index 4d133a782b6dd369b797eb336d82bb129ac4fd2e..7018202f144b5e38566e2f737aa20f691f6ba3cc 100644 (file)
@@ -70,8 +70,8 @@ REVOKE [ GRANT OPTION FOR ]
 
 REVOKE [ GRANT OPTION FOR ]
     { EXECUTE | ALL [ PRIVILEGES ] }
-    ON { FUNCTION <replaceable>function_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">arg_name</replaceable> ] <replaceable class="parameter">arg_type</replaceable> [, ...] ] ) ] [, ...]
-         | ALL FUNCTIONS IN SCHEMA <replaceable>schema_name</replaceable> [, ...] }
+    ON { { FUNCTION | PROCEDURE | ROUTINE } <replaceable>function_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">arg_name</replaceable> ] <replaceable class="parameter">arg_type</replaceable> [, ...] ] ) ] [, ...]
+         | ALL { FUNCTIONS | PROCEDURES | ROUTINES } IN SCHEMA <replaceable>schema_name</replaceable> [, ...] }
     FROM { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...]
     [ CASCADE | RESTRICT ]
 
index d52113e0359b7bf206e6290d0894926107142480..e9cfdec9f944642ae56ffe12b4deb4ba962cf253 100644 (file)
@@ -34,8 +34,10 @@ SECURITY LABEL [ FOR <replaceable class="parameter">provider</replaceable> ] ON
   LARGE OBJECT <replaceable class="parameter">large_object_oid</replaceable> |
   MATERIALIZED VIEW <replaceable class="parameter">object_name</replaceable> |
   [ PROCEDURAL ] LANGUAGE <replaceable class="parameter">object_name</replaceable> |
+  PROCEDURE <replaceable class="parameter">procedure_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] |
   PUBLICATION <replaceable class="parameter">object_name</replaceable> |
   ROLE <replaceable class="parameter">object_name</replaceable> |
+  ROUTINE <replaceable class="parameter">routine_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ] |
   SCHEMA <replaceable class="parameter">object_name</replaceable> |
   SEQUENCE <replaceable class="parameter">object_name</replaceable> |
   SUBSCRIPTION <replaceable class="parameter">object_name</replaceable> |
@@ -93,10 +95,12 @@ SECURITY LABEL [ FOR <replaceable class="parameter">provider</replaceable> ] ON
     <term><replaceable class="parameter">table_name.column_name</replaceable></term>
     <term><replaceable class="parameter">aggregate_name</replaceable></term>
     <term><replaceable class="parameter">function_name</replaceable></term>
+    <term><replaceable class="parameter">procedure_name</replaceable></term>
+    <term><replaceable class="parameter">routine_name</replaceable></term>
     <listitem>
      <para>
       The name of the object to be labeled.  Names of tables,
-      aggregates, domains, foreign tables, functions, sequences, types, and
+      aggregates, domains, foreign tables, functions, procedures, routines, sequences, types, and
       views can be schema-qualified.
      </para>
     </listitem>
@@ -119,7 +123,7 @@ SECURITY LABEL [ FOR <replaceable class="parameter">provider</replaceable> ] ON
 
     <listitem>
      <para>
-      The mode of a function or aggregate
+      The mode of a function, procedure, or aggregate
       argument: <literal>IN</literal>, <literal>OUT</literal>,
       <literal>INOUT</literal>, or <literal>VARIADIC</literal>.
       If omitted, the default is <literal>IN</literal>.
@@ -137,7 +141,7 @@ SECURITY LABEL [ FOR <replaceable class="parameter">provider</replaceable> ] ON
 
     <listitem>
      <para>
-      The name of a function or aggregate argument.
+      The name of a function, procedure, or aggregate argument.
       Note that <command>SECURITY LABEL</command> does not actually
       pay any attention to argument names, since only the argument data
       types are needed to determine the function's identity.
@@ -150,7 +154,7 @@ SECURITY LABEL [ FOR <replaceable class="parameter">provider</replaceable> ] ON
 
     <listitem>
      <para>
-      The data type of a function or aggregate argument.
+      The data type of a function, procedure, or aggregate argument.
      </para>
     </listitem>
    </varlistentry>
index d20eaa87e76c0f65546df90f8f6da1873f832d9f..d27fb414f7c55a369db99b43ce995a8717c853ea 100644 (file)
    &alterOperatorClass;
    &alterOperatorFamily;
    &alterPolicy;
+   &alterProcedure;
    &alterPublication;
    &alterRole;
+   &alterRoutine;
    &alterRule;
    &alterSchema;
    &alterSequence;
@@ -76,6 +78,7 @@
    &alterView;
    &analyze;
    &begin;
+   &call;
    &checkpoint;
    &close;
    &cluster;
    &createOperatorClass;
    &createOperatorFamily;
    &createPolicy;
+   &createProcedure;
    &createPublication;
    &createRole;
    &createRule;
    &dropOperatorFamily;
    &dropOwned;
    &dropPolicy;
+   &dropProcedure;
    &dropPublication;
    &dropRole;
+   &dropRoutine;
    &dropRule;
    &dropSchema;
    &dropSequence;
index 508ee7a96c0047a2bbfa9dfbbc92da22bfd4e133..bbc3766cc21ef1c63cb422552ff00ec171564bc0 100644 (file)
   </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>
 
index ccde66a7dd71a2282b4e7c37688356a4ca7f87d2..e481cf3d118f78328d5a08814130639eaa82f567 100644 (file)
@@ -482,6 +482,14 @@ ExecuteGrantStmt(GrantStmt *stmt)
                        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");
@@ -584,6 +592,8 @@ ExecGrantStmt_oids(InternalGrant *istmt)
                        ExecGrant_ForeignServer(istmt);
                        break;
                case ACL_OBJECT_FUNCTION:
+               case ACL_OBJECT_PROCEDURE:
+               case ACL_OBJECT_ROUTINE:
                        ExecGrant_Function(istmt);
                        break;
                case ACL_OBJECT_LANGUAGE:
@@ -671,7 +681,7 @@ objectNamesToOids(GrantObjectType objtype, List *objnames)
                                ObjectWithArgs *func = (ObjectWithArgs *) lfirst(cell);
                                Oid                     funcid;
 
-                               funcid = LookupFuncWithArgs(func, false);
+                               funcid = LookupFuncWithArgs(OBJECT_FUNCTION, func, false);
                                objects = lappend_oid(objects, funcid);
                        }
                        break;
@@ -709,6 +719,26 @@ objectNamesToOids(GrantObjectType objtype, List *objnames)
                                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)
                        {
@@ -785,19 +815,39 @@ objectsInSchemaToOids(GrantObjectType objtype, List *nspnames)
                                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)
                                        {
@@ -955,6 +1005,14 @@ ExecAlterDefaultPrivilegesStmt(ParseState *pstate, AlterDefaultPrivilegesStmt *s
                        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");
@@ -1423,7 +1481,7 @@ RemoveRoleFromObjectACL(Oid roleid, Oid classid, Oid objid)
                                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;
index 236f6be37e846f5394527ffc70f9cbabe574c2c5..360725d59a3971b9c5876a0f8897fc23b81f057a 100644 (file)
@@ -1413,7 +1413,8 @@ CREATE VIEW routines AS
            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,
@@ -1422,7 +1423,8 @@ CREATE VIEW routines AS
            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,
@@ -1440,7 +1442,7 @@ CREATE VIEW routines AS
            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,
@@ -1462,7 +1464,8 @@ CREATE VIEW routines AS
            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,
@@ -1503,13 +1506,15 @@ CREATE VIEW routines AS
            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;
 
index 8d55c76fc4afe4373c4b39ace537895501243137..9553675975d233dae5a813c20f9eb9b3062a420e 100644 (file)
@@ -566,6 +566,9 @@ static const struct object_type_map
        {
                "function", OBJECT_FUNCTION
        },
+       {
+               "procedure", OBJECT_PROCEDURE
+       },
        /* OCLASS_TYPE */
        {
                "type", OBJECT_TYPE
@@ -884,13 +887,11 @@ get_object_address(ObjectType objtype, Node *object,
                                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:
@@ -2025,6 +2026,8 @@ pg_get_object_address(PG_FUNCTION_ARGS)
         */
        if (type == OBJECT_AGGREGATE ||
                type == OBJECT_FUNCTION ||
+               type == OBJECT_PROCEDURE ||
+               type == OBJECT_ROUTINE ||
                type == OBJECT_OPERATOR ||
                type == OBJECT_CAST ||
                type == OBJECT_AMOP ||
@@ -2168,6 +2171,8 @@ pg_get_object_address(PG_FUNCTION_ARGS)
                        objnode = (Node *) list_make2(name, args);
                        break;
                case OBJECT_FUNCTION:
+               case OBJECT_PROCEDURE:
+               case OBJECT_ROUTINE:
                case OBJECT_AGGREGATE:
                case OBJECT_OPERATOR:
                        {
@@ -2253,6 +2258,8 @@ check_object_ownership(Oid roleid, ObjectType objtype, ObjectAddress address,
                        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));
@@ -4026,6 +4033,8 @@ getProcedureTypeDescription(StringInfo buffer, Oid procid)
 
        if (procForm->proisagg)
                appendStringInfoString(buffer, "aggregate");
+       else if (procForm->prorettype == InvalidOid)
+               appendStringInfoString(buffer, "procedure");
        else
                appendStringInfoString(buffer, "function");
 
index 47916cfb544f552eff4a55970aae09f12f9cd78e..7d05e4bdb22cbad3dfc52c530840a35fc1189ff7 100644 (file)
@@ -857,7 +857,8 @@ fmgr_sql_validator(PG_FUNCTION_ARGS)
 
        /* 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))
index adc9877e79ef83c5adfb4718f9af8fc716dc38d1..2e2ee883e260c8a37dd4e5a42afcf771b18227a5 100644 (file)
@@ -307,7 +307,7 @@ DefineAggregate(ParseState *pstate, List *name, List *args, bool oldstyle, List
                interpret_function_parameter_list(pstate,
                                                                                  args,
                                                                                  InvalidOid,
-                                                                                 true, /* is an aggregate */
+                                                                                 OBJECT_AGGREGATE,
                                                                                  &parameterTypes,
                                                                                  &allParameterTypes,
                                                                                  &parameterModes,
index 4f8147907c4e54a23d3f708b1186d5f1d30d5d9a..21e3f1efe1060e8a4aad334faef3b482a09a7f59 100644 (file)
@@ -378,6 +378,8 @@ ExecRenameStmt(RenameStmt *stmt)
                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:
@@ -495,6 +497,8 @@ ExecAlterObjectSchemaStmt(AlterObjectSchemaStmt *stmt,
                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:
@@ -842,6 +846,8 @@ ExecAlterOwnerStmt(AlterOwnerStmt *stmt)
                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:
index 2b30677d6f917bf5db9b3b2d0a6dc054ae327e9c..7e6baa1928d008208d415ea36fca438bcae6441f 100644 (file)
@@ -26,6 +26,7 @@
 #include "nodes/makefuncs.h"
 #include "parser/parse_type.h"
 #include "utils/builtins.h"
+#include "utils/lsyscache.h"
 #include "utils/syscache.h"
 
 
@@ -91,21 +92,12 @@ RemoveObjects(DropStmt *stmt)
                 */
                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. */
@@ -338,6 +330,32 @@ does_not_exist_skipping(ObjectType objtype, Node *object)
                                }
                                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);
index fa7d0d015aa8dda1e2b861758b788462217ca5d8..a602c20b4161b694d0570e4c2dff2be6d729637f 100644 (file)
@@ -106,8 +106,10 @@ static event_trigger_support_data event_trigger_support[] = {
        {"OPERATOR CLASS", true},
        {"OPERATOR FAMILY", true},
        {"POLICY", true},
+       {"PROCEDURE", true},
        {"PUBLICATION", true},
        {"ROLE", false},
+       {"ROUTINE", true},
        {"RULE", true},
        {"SCHEMA", true},
        {"SEQUENCE", true},
@@ -1103,8 +1105,10 @@ EventTriggerSupportsObjectType(ObjectType obtype)
                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:
@@ -1215,6 +1219,8 @@ EventTriggerSupportsGrantObjectType(GrantObjectType objtype)
                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;
 
@@ -2243,6 +2249,10 @@ stringify_grantobjtype(GrantObjectType objtype)
                        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:
@@ -2285,6 +2295,10 @@ stringify_adefprivs_objtype(GrantObjectType objtype)
                        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:
index 7de844b2cadff52a6d295eb66c30c0278f58d8e1..2a9c90133d182be3bf3b7e3aa25984fd1db4b579 100644 (file)
@@ -51,6 +51,8 @@
 #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"
@@ -179,7 +181,7 @@ void
 interpret_function_parameter_list(ParseState *pstate,
                                                                  List *parameters,
                                                                  Oid languageOid,
-                                                                 bool is_aggregate,
+                                                                 ObjectType objtype,
                                                                  oidvector **parameterTypes,
                                                                  ArrayType **allParameterTypes,
                                                                  ArrayType **parameterModes,
@@ -233,7 +235,7 @@ interpret_function_parameter_list(ParseState *pstate,
                                                         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",
@@ -262,16 +264,28 @@ interpret_function_parameter_list(ParseState *pstate,
 
                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)
                {
@@ -451,6 +465,7 @@ interpret_function_parameter_list(ParseState *pstate,
  */
 static bool
 compute_common_attribute(ParseState *pstate,
+                                                bool is_procedure,
                                                 DefElem *defel,
                                                 DefElem **volatility_item,
                                                 DefElem **strict_item,
@@ -463,6 +478,8 @@ compute_common_attribute(ParseState *pstate,
 {
        if (strcmp(defel->defname, "volatility") == 0)
        {
+               if (is_procedure)
+                       goto procedure_error;
                if (*volatility_item)
                        goto duplicate_error;
 
@@ -470,6 +487,8 @@ compute_common_attribute(ParseState *pstate,
        }
        else if (strcmp(defel->defname, "strict") == 0)
        {
+               if (is_procedure)
+                       goto procedure_error;
                if (*strict_item)
                        goto duplicate_error;
 
@@ -484,6 +503,8 @@ compute_common_attribute(ParseState *pstate,
        }
        else if (strcmp(defel->defname, "leakproof") == 0)
        {
+               if (is_procedure)
+                       goto procedure_error;
                if (*leakproof_item)
                        goto duplicate_error;
 
@@ -495,6 +516,8 @@ compute_common_attribute(ParseState *pstate,
        }
        else if (strcmp(defel->defname, "cost") == 0)
        {
+               if (is_procedure)
+                       goto procedure_error;
                if (*cost_item)
                        goto duplicate_error;
 
@@ -502,6 +525,8 @@ compute_common_attribute(ParseState *pstate,
        }
        else if (strcmp(defel->defname, "rows") == 0)
        {
+               if (is_procedure)
+                       goto procedure_error;
                if (*rows_item)
                        goto duplicate_error;
 
@@ -509,6 +534,8 @@ compute_common_attribute(ParseState *pstate,
        }
        else if (strcmp(defel->defname, "parallel") == 0)
        {
+               if (is_procedure)
+                       goto procedure_error;
                if (*parallel_item)
                        goto duplicate_error;
 
@@ -526,6 +553,13 @@ 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
@@ -603,6 +637,7 @@ update_proconfig_value(ArrayType *a, List *set_items)
  */
 static void
 compute_attributes_sql_style(ParseState *pstate,
+                                                        bool is_procedure,
                                                         List *options,
                                                         List **as,
                                                         char **language,
@@ -669,9 +704,15 @@ compute_attributes_sql_style(ParseState *pstate,
                                                (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,
@@ -762,7 +803,7 @@ compute_attributes_sql_style(ParseState *pstate,
  *------------
  */
 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;
 
@@ -771,10 +812,22 @@ compute_attributes_with_style(ParseState *pstate, List *parameters, bool *isStri
                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;
                }
@@ -916,6 +969,7 @@ CreateFunction(ParseState *pstate, CreateFunctionStmt *stmt)
 
        /* override attributes from explicit list */
        compute_attributes_sql_style(pstate,
+                                                                stmt->is_procedure,
                                                                 stmt->options,
                                                                 &as_clause, &language, &transformDefElem,
                                                                 &isWindowFunc, &volatility,
@@ -990,7 +1044,7 @@ CreateFunction(ParseState *pstate, CreateFunctionStmt *stmt)
        interpret_function_parameter_list(pstate,
                                                                          stmt->parameters,
                                                                          languageOid,
-                                                                         false,        /* not an aggregate */
+                                                                         stmt->is_procedure ? OBJECT_PROCEDURE : OBJECT_FUNCTION,
                                                                          &parameterTypes,
                                                                          &allParameterTypes,
                                                                          &parameterModes,
@@ -999,7 +1053,14 @@ CreateFunction(ParseState *pstate, CreateFunctionStmt *stmt)
                                                                          &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,
@@ -1045,7 +1106,7 @@ CreateFunction(ParseState *pstate, CreateFunctionStmt *stmt)
                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);
@@ -1168,6 +1229,7 @@ AlterFunction(ParseState *pstate, AlterFunctionStmt *stmt)
        HeapTuple       tup;
        Oid                     funcOid;
        Form_pg_proc procForm;
+       bool            is_procedure;
        Relation        rel;
        ListCell   *l;
        DefElem    *volatility_item = NULL;
@@ -1182,7 +1244,7 @@ AlterFunction(ParseState *pstate, AlterFunctionStmt *stmt)
 
        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 */
@@ -1201,12 +1263,15 @@ AlterFunction(ParseState *pstate, AlterFunctionStmt *stmt)
                                 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,
@@ -1472,7 +1537,7 @@ CreateCast(CreateCastStmt *stmt)
        {
                Form_pg_proc procstruct;
 
-               funcid = LookupFuncWithArgs(stmt->func, false);
+               funcid = LookupFuncWithArgs(OBJECT_FUNCTION, stmt->func, false);
 
                tuple = SearchSysCache1(PROCOID, ObjectIdGetDatum(funcid));
                if (!HeapTupleIsValid(tuple))
@@ -1853,7 +1918,7 @@ CreateTransform(CreateTransformStmt *stmt)
         */
        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));
@@ -1879,7 +1944,7 @@ CreateTransform(CreateTransformStmt *stmt)
 
        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));
@@ -2168,3 +2233,80 @@ ExecuteDoStmt(DoStmt *stmt)
        /* 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);
+}
index 1641e68abec05097d71f860776532ba5745d42fc..35c7c67bf5137337615e342117cda3bbaeadcf27 100644 (file)
@@ -520,7 +520,7 @@ DefineOpClass(CreateOpClassStmt *stmt)
                                                         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 */
@@ -894,7 +894,7 @@ AlterOpFamilyAdd(AlterOpFamilyStmt *stmt, Oid amoid, Oid opfamilyoid,
                                                         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 */
index 98eb777421bbaaf238ef1ee4ecc6581edfd84d34..3caa343723515e98ced8ef19d204583754de3746 100644 (file)
@@ -390,6 +390,7 @@ sql_fn_post_column_ref(ParseState *pstate, ColumnRef *cref, Node *var)
                                                                  list_make1(param),
                                                                  pstate->p_last_srf,
                                                                  NULL,
+                                                                 false,
                                                                  cref->location);
        }
 
@@ -658,7 +659,8 @@ init_sql_fcache(FmgrInfo *finfo, Oid collation, bool lazyEvalOK)
        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;
@@ -1321,8 +1323,8 @@ fmgr_sql(PG_FUNCTION_ARGS)
                }
                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;
                }
@@ -1546,7 +1548,10 @@ check_sql_fn_retval(Oid func_id, Oid rettype, List *queryTreeList,
        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
@@ -1591,7 +1596,7 @@ check_sql_fn_retval(Oid func_id, Oid rettype, List *queryTreeList,
        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",
index d9ff8a7e510a2f0027f19e8d4d1ba6c57408aa53..aff9a62106d64bd52b68e98487fd968d40aa3016 100644 (file)
@@ -3210,6 +3210,16 @@ _copyClosePortalStmt(const ClosePortalStmt *from)
        return newnode;
 }
 
+static CallStmt *
+_copyCallStmt(const CallStmt *from)
+{
+       CallStmt *newnode = makeNode(CallStmt);
+
+       COPY_NODE_FIELD(funccall);
+
+       return newnode;
+}
+
 static ClusterStmt *
 _copyClusterStmt(const ClusterStmt *from)
 {
@@ -3411,6 +3421,7 @@ _copyCreateFunctionStmt(const CreateFunctionStmt *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);
 
@@ -3435,6 +3446,7 @@ _copyAlterFunctionStmt(const AlterFunctionStmt *from)
 {
        AlterFunctionStmt *newnode = makeNode(AlterFunctionStmt);
 
+       COPY_SCALAR_FIELD(objtype);
        COPY_NODE_FIELD(func);
        COPY_NODE_FIELD(actions);
 
@@ -5104,6 +5116,9 @@ copyObjectImpl(const void *from)
                case T_ClosePortalStmt:
                        retval = _copyClosePortalStmt(from);
                        break;
+               case T_CallStmt:
+                       retval = _copyCallStmt(from);
+                       break;
                case T_ClusterStmt:
                        retval = _copyClusterStmt(from);
                        break;
index 2866fd7b4afd2bc73c2d42b69c4f948b7344b41f..2e869a9d5d8473c03befb3723d1471e4c8fb78e4 100644 (file)
@@ -1201,6 +1201,14 @@ _equalClosePortalStmt(const ClosePortalStmt *a, const ClosePortalStmt *b)
        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)
 {
@@ -1364,6 +1372,7 @@ _equalCreateFunctionStmt(const CreateFunctionStmt *a, const CreateFunctionStmt *
        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);
 
@@ -1384,6 +1393,7 @@ _equalFunctionParameter(const FunctionParameter *a, const FunctionParameter *b)
 static bool
 _equalAlterFunctionStmt(const AlterFunctionStmt *a, const AlterFunctionStmt *b)
 {
+       COMPARE_SCALAR_FIELD(objtype);
        COMPARE_NODE_FIELD(func);
        COMPARE_NODE_FIELD(actions);
 
@@ -3246,6 +3256,9 @@ equal(const void *a, const void *b)
                case T_ClosePortalStmt:
                        retval = _equalClosePortalStmt(a, b);
                        break;
+               case T_CallStmt:
+                       retval = _equalCallStmt(a, b);
+                       break;
                case T_ClusterStmt:
                        retval = _equalClusterStmt(a, b);
                        break;
index e5e2956564637e8a66b99931a8bcc67db4c7228d..6a2d5ad760f47b041ba9259ded08a2e37f00995d 100644 (file)
@@ -4401,6 +4401,7 @@ inline_function(Oid funcid, Oid result_type, Oid result_collid,
        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))
index c301ca465d471e7173dcbc97b4592c89fb6fed6c..ebfc94f89693efa6d0b8eade705648f9ee91c231 100644 (file)
@@ -253,7 +253,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
                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
@@ -611,7 +611,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
        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
@@ -660,14 +660,14 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
        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
@@ -845,6 +845,7 @@ stmt :
                        | AlterTSDictionaryStmt
                        | AlterUserMappingStmt
                        | AnalyzeStmt
+                       | CallStmt
                        | CheckPointStmt
                        | ClosePortalStmt
                        | ClusterStmt
@@ -940,6 +941,20 @@ stmt :
                                { $$ = NULL; }
                ;
 
+/*****************************************************************************
+ *
+ * CALL statement
+ *
+ *****************************************************************************/
+
+CallStmt:      CALL func_application
+                               {
+                                       CallStmt *n = makeNode(CallStmt);
+                                       n->funccall = castNode(FuncCall, $2);
+                                       $$ = (Node *)n;
+                               }
+               ;
+
 /*****************************************************************************
  *
  * Create a new Postgres DBMS role
@@ -4554,6 +4569,24 @@ AlterExtensionContentsStmt:
                                        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);
@@ -6436,6 +6469,22 @@ CommentStmt:
                                        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);
@@ -6614,6 +6663,26 @@ SecLabelStmt:
                                        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; }
@@ -6977,6 +7046,22 @@ privilege_target:
                                        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));
@@ -7057,6 +7142,22 @@ privilege_target:
                                        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;
+                               }
                ;
 
 
@@ -7213,6 +7314,7 @@ DefACLAction:
 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; }
@@ -7413,6 +7515,18 @@ CreateFunctionStmt:
                                        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:
@@ -7830,7 +7944,7 @@ table_func_column_list:
                ;
 
 /*****************************************************************************
- * 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
@@ -7841,6 +7955,23 @@ AlterFunctionStmt:
                        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;
@@ -7865,6 +7996,8 @@ opt_restrict:
  *             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 ]
  *
@@ -7891,6 +8024,46 @@ RemoveFuncStmt:
                                        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:
@@ -8348,6 +8521,15 @@ RenameStmt: ALTER AGGREGATE aggregate_with_argtypes RENAME TO name
                                        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);
@@ -8357,6 +8539,15 @@ RenameStmt: ALTER AGGREGATE aggregate_with_argtypes RENAME TO name
                                        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);
@@ -8736,6 +8927,22 @@ AlterObjectDependsStmt:
                                        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);
@@ -8851,6 +9058,24 @@ AlterObjectSchemaStmt:
                                        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);
@@ -9126,6 +9351,22 @@ AlterOwnerStmt: ALTER AGGREGATE aggregate_with_argtypes OWNER TO RoleSpec
                                        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);
@@ -14689,6 +14930,7 @@ unreserved_keyword:
                        | BEGIN_P
                        | BY
                        | CACHE
+                       | CALL
                        | CALLED
                        | CASCADE
                        | CASCADED
@@ -14848,6 +15090,7 @@ unreserved_keyword:
                        | PRIVILEGES
                        | PROCEDURAL
                        | PROCEDURE
+                       | PROCEDURES
                        | PROGRAM
                        | PUBLICATION
                        | QUOTE
@@ -14874,6 +15117,8 @@ unreserved_keyword:
                        | ROLE
                        | ROLLBACK
                        | ROLLUP
+                       | ROUTINE
+                       | ROUTINES
                        | ROWS
                        | RULE
                        | SAVEPOINT
index 64111f315e33a56bac17eb66549c7e3ef2076548..4c4f4cdc3d7ac595005ea8d2cb0fac636a2f7c99 100644 (file)
@@ -508,6 +508,14 @@ check_agglevels_and_constraints(ParseState *pstate, Node *expr)
 
                        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
@@ -883,6 +891,9 @@ transformWindowFuncCall(ParseState *pstate, WindowFunc *wfunc,
                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
index 86d1da067755987327894f674fce2c66487f459e..29f9da796fc5651545208ec7375ba3bd4e48f97b 100644 (file)
@@ -480,6 +480,7 @@ transformIndirection(ParseState *pstate, A_Indirection *ind)
                                                                                  list_make1(result),
                                                                                  last_srf,
                                                                                  NULL,
+                                                                                 false,
                                                                                  location);
                        if (newresult == NULL)
                                unknown_attribute(pstate, result, strVal(n), location);
@@ -629,6 +630,7 @@ transformColumnRef(ParseState *pstate, ColumnRef *cref)
                                                                                         list_make1(node),
                                                                                         pstate->p_last_srf,
                                                                                         NULL,
+                                                                                        false,
                                                                                         cref->location);
                                }
                                break;
@@ -676,6 +678,7 @@ transformColumnRef(ParseState *pstate, ColumnRef *cref)
                                                                                         list_make1(node),
                                                                                         pstate->p_last_srf,
                                                                                         NULL,
+                                                                                        false,
                                                                                         cref->location);
                                }
                                break;
@@ -736,6 +739,7 @@ transformColumnRef(ParseState *pstate, ColumnRef *cref)
                                                                                         list_make1(node),
                                                                                         pstate->p_last_srf,
                                                                                         NULL,
+                                                                                        false,
                                                                                         cref->location);
                                }
                                break;
@@ -1477,6 +1481,7 @@ transformFuncCall(ParseState *pstate, FuncCall *fn)
                                                         targs,
                                                         last_srf,
                                                         fn,
+                                                        false,
                                                         fn->location);
 }
 
@@ -1812,6 +1817,7 @@ transformSubLink(ParseState *pstate, SubLink *sublink)
                case EXPR_KIND_RETURNING:
                case EXPR_KIND_VALUES:
                case EXPR_KIND_VALUES_SINGLE:
+               case EXPR_KIND_CALL:
                        /* okay */
                        break;
                case EXPR_KIND_CHECK_CONSTRAINT:
@@ -3462,6 +3468,8 @@ ParseExprKindName(ParseExprKind exprKind)
                        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
index a11843332b0847823c71eb6bf4bbf1dad0c7d8a7..2f20516e766515fbd122634df460c73bc421a0fa 100644 (file)
@@ -71,7 +71,7 @@ static Node *ParseComplexProjection(ParseState *pstate, const char *funcname,
  */
 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);
@@ -263,7 +263,7 @@ ParseFuncOrColumn(ParseState *pstate, List *funcname, List *fargs,
                                                   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
@@ -306,6 +306,26 @@ ParseFuncOrColumn(ParseState *pstate, List *funcname, List *fargs,
                                         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)
        {
@@ -635,7 +655,7 @@ ParseFuncOrColumn(ParseState *pstate, List *funcname, List *fargs,
                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);
 
@@ -1589,6 +1609,8 @@ func_get_detail(List *funcname,
                        result = FUNCDETAIL_AGGREGATE;
                else if (pform->proiswindow)
                        result = FUNCDETAIL_WINDOWFUNC;
+               else if (pform->prorettype == InvalidOid)
+                       result = FUNCDETAIL_PROCEDURE;
                else
                        result = FUNCDETAIL_NORMAL;
                ReleaseSysCache(ftup);
@@ -1984,16 +2006,28 @@ LookupFuncName(List *funcname, int nargs, const Oid *argtypes, bool noError)
 
 /*
  * 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)
@@ -2013,90 +2047,100 @@ LookupFuncWithArgs(ObjectWithArgs *func, bool noError)
                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,
@@ -2236,6 +2280,9 @@ check_srf_call_placement(ParseState *pstate, Node *last_srf, int location)
                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
index 82a707af7b8b2d7e7e1942176b53966387c450c7..4da1f8f6430816c2c2e807f5b32e4ed9a74542ea 100644 (file)
@@ -657,6 +657,10 @@ standard_ProcessUtility(PlannedStmt *pstmt,
                        }
                        break;
 
+               case T_CallStmt:
+                       ExecuteCallStmt(pstate, castNode(CallStmt, parsetree));
+                       break;
+
                case T_ClusterStmt:
                        /* we choose to allow this during "read only" transactions */
                        PreventCommandDuringRecovery("CLUSTER");
@@ -1957,9 +1961,15 @@ AlterObjectTypeCommandTag(ObjectType objtype)
                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;
@@ -2261,6 +2271,12 @@ CreateCommandTag(Node *parsetree)
                                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;
@@ -2359,7 +2375,20 @@ CreateCommandTag(Node *parsetree)
                        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:
@@ -2438,7 +2467,10 @@ CreateCommandTag(Node *parsetree)
                        break;
 
                case T_CreateFunctionStmt:
-                       tag = "CREATE FUNCTION";
+                       if (((CreateFunctionStmt *) parsetree)->is_procedure)
+                               tag = "CREATE PROCEDURE";
+                       else
+                               tag = "CREATE FUNCTION";
                        break;
 
                case T_IndexStmt:
@@ -2493,6 +2525,10 @@ CreateCommandTag(Node *parsetree)
                        tag = "LOAD";
                        break;
 
+               case T_CallStmt:
+                       tag = "CALL";
+                       break;
+
                case T_ClusterStmt:
                        tag = "CLUSTER";
                        break;
@@ -3116,6 +3152,10 @@ GetCommandLogLevel(Node *parsetree)
                        lev = LOGSTMT_ALL;
                        break;
 
+               case T_CallStmt:
+                       lev = LOGSTMT_ALL;
+                       break;
+
                case T_ClusterStmt:
                        lev = LOGSTMT_DDL;
                        break;
index 06cf32f5d75be19cd605d1158261db267915b4f6..8514c21c407e176c36c2f73a4e928aae7e3af315 100644 (file)
@@ -2691,6 +2691,12 @@ pg_get_function_result(PG_FUNCTION_ARGS)
        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);
index 0ea2f2bc54cc31ccd5ea2988025447a3c4fca4d0..52113607775c3c0c5d2e2ade7baa1fef91b0cdfc 100644 (file)
@@ -1614,6 +1614,25 @@ func_parallel(Oid funcid)
        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.
index 70d8f24d173625b2cc0ededec280770ea2f75f26..12290a1aae6ac9fc69fd071f8d66a89340350ee7 100644 (file)
@@ -33,7 +33,7 @@ static void AddAcl(PQExpBuffer aclbuf, const char *keyword,
  *     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
@@ -524,6 +524,9 @@ do { \
        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 ||
index ec2fa8b9b9a3413cacdac1a1fdab9786734578e6..41741aefbc572e2a7d10361b1b332506381b67cc 100644 (file)
@@ -2889,7 +2889,8 @@ _tocEntryRequired(TocEntry *te, teSection curSection, RestoreOptions *ropt)
                        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;
@@ -3388,7 +3389,8 @@ _getObjectDescription(PQExpBuffer buf, TocEntry *te, ArchiveHandle *AH)
                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);
@@ -3560,6 +3562,7 @@ _printTocEntry(ArchiveHandle *AH, TocEntry *te, bool isData)
                        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 ||
index d8fb356130237edc4ccf6171abf7d9c70e1dafbe..e6701aaa782ce14b7dbd20422bcca5d6faf14dd9 100644 (file)
@@ -11349,6 +11349,7 @@ dumpFunc(Archive *fout, FuncInfo *finfo)
        char       *funcargs;
        char       *funciargs;
        char       *funcresult;
+       bool            is_procedure;
        char       *proallargtypes;
        char       *proargmodes;
        char       *proargnames;
@@ -11370,6 +11371,7 @@ dumpFunc(Archive *fout, FuncInfo *finfo)
        char      **argnames = NULL;
        char      **configitems = NULL;
        int                     nconfigitems = 0;
+       const char *keyword;
        int                     i;
 
        /* Skip if not to be dumped */
@@ -11513,7 +11515,11 @@ dumpFunc(Archive *fout, FuncInfo *finfo)
        {
                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
@@ -11522,6 +11528,7 @@ dumpFunc(Archive *fout, FuncInfo *finfo)
                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"));
@@ -11653,22 +11660,29 @@ dumpFunc(Archive *fout, FuncInfo *finfo)
 
        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);
@@ -11775,7 +11789,7 @@ dumpFunc(Archive *fout, FuncInfo *finfo)
 
        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);
@@ -11786,7 +11800,7 @@ dumpFunc(Archive *fout, FuncInfo *finfo)
                                         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);
@@ -11803,7 +11817,7 @@ dumpFunc(Archive *fout, FuncInfo *finfo)
                                         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,
index fa3b56a426f08e2e007f2e4b60b9df969bcd737b..7cf9bdadb2e6b9e81a57f9c7cacf12c075cdca0b 100644 (file)
@@ -3654,6 +3654,44 @@ qr/^\QCREATE DEFAULT CONVERSION test_conversion FOR 'LATIN1' TO 'UTF8' FROM iso8
                        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,
index 804a84a0c91943a57412941ce2af566dbfc42dce..3fc69c46c061c51333070b2c7f7d2e9e76566606 100644 (file)
@@ -353,6 +353,7 @@ describeFunctions(const char *functypes, const char *pattern, bool verbose, bool
                                                  " 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\"",
@@ -361,8 +362,9 @@ describeFunctions(const char *functypes, const char *pattern, bool verbose, bool
                /* 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,
@@ -407,7 +409,7 @@ describeFunctions(const char *functypes, const char *pattern, bool verbose, bool
                /* translator: "agg" is short for "aggregate" */
                                                  gettext_noop("agg"),
                                                  gettext_noop("trigger"),
-                                                 gettext_noop("normal"),
+                                                 gettext_noop("func"),
                                                  gettext_noop("Type"));
        else
                appendPQExpBuffer(&buf,
@@ -424,7 +426,7 @@ describeFunctions(const char *functypes, const char *pattern, bool verbose, bool
                /* translator: "agg" is short for "aggregate" */
                                                  gettext_noop("agg"),
                                                  gettext_noop("trigger"),
-                                                 gettext_noop("normal"),
+                                                 gettext_noop("func"),
                                                  gettext_noop("Type"));
 
        if (verbose)
index b3e3799c132057511f1f65f107d7c7d8910c4b66..468e50aa3174fd1cbacef94879bb3eaedc6aefb9 100644 (file)
@@ -397,7 +397,7 @@ static const SchemaQuery Query_for_list_of_functions = {
        /* catname */
        "pg_catalog.pg_proc p",
        /* selcondition */
-       NULL,
+       "p.prorettype <> 0",
        /* viscondition */
        "pg_catalog.pg_function_is_visible(p.oid)",
        /* namespace */
@@ -423,6 +423,36 @@ static const SchemaQuery Query_for_list_of_indexes = {
        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",
@@ -1032,8 +1062,10 @@ static const pgsql_thing_t words_after_create[] = {
        {"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},
@@ -1407,7 +1439,7 @@ psql_completion(const char *text, int start, int end)
 
        /* 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",
@@ -1520,11 +1552,11 @@ psql_completion(const char *text, int start, int end)
        /* 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");
@@ -2145,6 +2177,11 @@ psql_completion(const char *text, int start, int end)
 /* 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'");
@@ -2176,6 +2213,7 @@ psql_completion(const char *text, int start, int end)
                        "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};
 
@@ -2685,7 +2723,7 @@ psql_completion(const char *text, int start, int end)
                                          "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) ||
@@ -2694,9 +2732,9 @@ psql_completion(const char *text, int start, int end)
                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");
@@ -2893,10 +2931,12 @@ psql_completion(const char *text, int start, int end)
                 * 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'"
@@ -2906,6 +2946,8 @@ psql_completion(const char *text, int start, int end)
                                                                           " 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'"
@@ -2913,7 +2955,10 @@ psql_completion(const char *text, int start, int end)
                                                                           " 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");
@@ -2934,6 +2979,10 @@ psql_completion(const char *text, int start, int end)
                        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"))
@@ -3163,7 +3212,7 @@ psql_completion(const char *text, int start, int end)
                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);
@@ -3233,8 +3282,8 @@ psql_completion(const char *text, int start, int end)
        /* 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 */
index a30ce6b81d88265d69d22e0f3b77847ecbcf003c..b13cf62beca9006678dc93a3789587b6bba0e8d3 100644 (file)
@@ -53,6 +53,6 @@
  */
 
 /*                                                     yyyymmddN */
-#define CATALOG_VERSION_NO     201711171
+#define CATALOG_VERSION_NO     201711301
 
 #endif
index bfead9af3d1bbd0c242abaab56f6ebe23dd679aa..52cbf61ccb066f88b2c55347c21f11b26886d57c 100644 (file)
@@ -59,12 +59,13 @@ extern void DropTransformById(Oid transformOid);
 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,
index 03dc5307e8a4e3ccb95fb58929cc77bcab263f67..c5b5115f5b4866ba63b6ecbd71843e07d02c3e65 100644 (file)
@@ -414,6 +414,7 @@ typedef enum NodeTag
        T_DropSubscriptionStmt,
        T_CreateStatsStmt,
        T_AlterCollationStmt,
+       T_CallStmt,
 
        /*
         * TAGS FOR PARSE TREE NODES (parsenodes.h)
index 34d6afc80f46c9bd7c29999652f4c0f060faabe4..2eaa6b2774018bfbf2a5c498bcb581414d3bc5b5 100644 (file)
@@ -1642,9 +1642,11 @@ typedef enum ObjectType
        OBJECT_OPERATOR,
        OBJECT_OPFAMILY,
        OBJECT_POLICY,
+       OBJECT_PROCEDURE,
        OBJECT_PUBLICATION,
        OBJECT_PUBLICATION_REL,
        OBJECT_ROLE,
+       OBJECT_ROUTINE,
        OBJECT_RULE,
        OBJECT_SCHEMA,
        OBJECT_SEQUENCE,
@@ -1856,6 +1858,8 @@ typedef enum GrantObjectType
        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;
@@ -2749,6 +2753,7 @@ typedef struct CreateFunctionStmt
        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;
@@ -2775,6 +2780,7 @@ typedef struct FunctionParameter
 typedef struct AlterFunctionStmt
 {
        NodeTag         type;
+       ObjectType      objtype;
        ObjectWithArgs *func;           /* name and args of function */
        List       *actions;            /* list of DefElem */
 } AlterFunctionStmt;
@@ -2799,6 +2805,16 @@ typedef struct InlineCodeBlock
        bool            langIsTrusted;  /* trusted property of the language */
 } InlineCodeBlock;
 
+/* ----------------------
+ *             CALL statement
+ * ----------------------
+ */
+typedef struct CallStmt
+{
+       NodeTag         type;
+       FuncCall   *funccall;
+} CallStmt;
+
 /* ----------------------
  *             Alter Object Rename Statement
  * ----------------------
index f50e45e886da8d3a120eecfb6dc3739b0a6bed1e..a9324000588ebdac139fd166867c7e48e13c11e6 100644 (file)
@@ -63,6 +63,7 @@ PG_KEYWORD("boolean", BOOLEAN_P, COL_NAME_KEYWORD)
 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)
@@ -310,6 +311,7 @@ PG_KEYWORD("prior", PRIOR, 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)
@@ -340,6 +342,8 @@ PG_KEYWORD("right", RIGHT, TYPE_FUNC_NAME_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)
index b4b6084b1bfd35c7bb7e72c326354e4569980848..fccccd21ed4ecea805b25b85bbc932ed7ee4b494 100644 (file)
@@ -24,6 +24,7 @@ typedef enum
        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 */
@@ -31,7 +32,8 @@ typedef enum
 
 
 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,
@@ -62,10 +64,8 @@ extern const char *func_signature_string(List *funcname, int nargs,
 
 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);
index f0e210ad8d85cc87ccf49c3d65187aa229cb5480..565bb3dc6cf0d6e6d3c16119bfcbaa584e4803c2 100644 (file)
@@ -67,7 +67,8 @@ typedef enum ParseExprKind
        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;
 
 
index 07208b56cef2d70905380484ef3244883e87b49e..b316cc594c6152bb4abd311bcb5aa51e65b1746f 100644 (file)
@@ -118,6 +118,7 @@ extern bool get_func_retset(Oid funcid);
 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);
index 68ba925efe4c567075e3a635b29640a8d274607c..1d613af02f6a1fdb529e02257d407b9f3bc52763 100644 (file)
@@ -2,7 +2,7 @@
 
 /* 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
index f60a62099d4613cfd94619739b2daf162170af73..19dc78188598db473833c62f3abb7b276b0e8838 100644 (file)
@@ -1460,13 +1460,13 @@ action : CONTINUE_P
                        $<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("()"));
@@ -1482,7 +1482,6 @@ ECPGKeywords: ECPGKeywords_vanames        { $$ = $1; }
                ;
 
 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"); }
index 3b52b8f3a291beb64833b0067e1937827b1edc44..848b2d48493fea15eec3ce74358dc4901c61a93c 100644 (file)
@@ -33,7 +33,6 @@ static const ScanKeyword ECPGScanKeywords[] = {
        {"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},
index 91d1296b21902bf1bac9e4341c98e4963bae2ca8..b829027d05dfb94481f0020c681bf32b4e368504 100644 (file)
@@ -55,7 +55,7 @@ endif # win32
 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),)
diff --git a/src/pl/plperl/expected/plperl_call.out b/src/pl/plperl/expected/plperl_call.out
new file mode 100644 (file)
index 0000000..4bccfcb
--- /dev/null
@@ -0,0 +1,29 @@
+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;
index a57393fbdd9d4830daa10b4b092d0fb1784e2e41..9f5313235f344c772794b3929b1a3878af7d17e1 100644 (file)
@@ -1915,7 +1915,7 @@ plperl_inline_handler(PG_FUNCTION_ARGS)
        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;
 
@@ -2481,7 +2481,7 @@ plperl_func_handler(PG_FUNCTION_ARGS)
                }
                retval = (Datum) 0;
        }
-       else
+       else if (prodesc->result_oid)
        {
                retval = plperl_sv_to_datum(perlret,
                                                                        prodesc->result_oid,
@@ -2826,7 +2826,7 @@ compile_plperl_function(Oid fn_oid, bool is_trigger, bool is_event_trigger)
                 * 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;
 
@@ -3343,7 +3343,7 @@ plperl_return_next_internal(SV *sv)
 
                tuplestore_puttuple(current_call_data->tuple_store, tuple);
        }
-       else
+       else if (prodesc->result_oid)
        {
                Datum           ret[1];
                bool            isNull[1];
diff --git a/src/pl/plperl/sql/plperl_call.sql b/src/pl/plperl/sql/plperl_call.sql
new file mode 100644 (file)
index 0000000..bd2b63b
--- /dev/null
@@ -0,0 +1,36 @@
+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;
index d0afa5924237511afbabd47cf9b98de932e5363d..f459c02f7be5687f3984ebed8d57d72ec18e2e86 100644 (file)
@@ -275,7 +275,6 @@ do_compile(FunctionCallInfo fcinfo,
        bool            isnull;
        char       *proc_source;
        HeapTuple       typeTup;
-       Form_pg_type typeStruct;
        PLpgSQL_variable *var;
        PLpgSQL_rec *rec;
        int                     i;
@@ -531,53 +530,58 @@ do_compile(FunctionCallInfo fcinfo,
                        /*
                         * 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:
index cf6120eea9a83bdb4d32de1dae9c0e6eee5e3496..ec480cb0ba8bd268b93636541c2a5cd2d6f9dacc 100644 (file)
@@ -462,7 +462,7 @@ plpgsql_exec_function(PLpgSQL_function *func, FunctionCallInfo fcinfo,
        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;
@@ -509,6 +509,12 @@ plpgsql_exec_function(PLpgSQL_function *func, FunctionCallInfo fcinfo,
        }
        else if (!estate.retisnull)
        {
+               if (!func->fn_rettype)
+               {
+                       ereport(ERROR,
+                                       (errmsg("cannot return a value from a procedure")));
+               }
+
                if (estate.retistuple)
                {
                        /*
index 7680d49cb6997d5533a4f265e841e4f01d7d3a1a..cc91afebde70e72061c3036c4023616613d8c63e 100644 (file)
@@ -78,6 +78,7 @@ REGRESS = \
        plpython_spi \
        plpython_newline \
        plpython_void \
+       plpython_call \
        plpython_params \
        plpython_setof \
        plpython_record \
diff --git a/src/pl/plpython/expected/plpython_call.out b/src/pl/plpython/expected/plpython_call.out
new file mode 100644 (file)
index 0000000..9078534
--- /dev/null
@@ -0,0 +1,35 @@
+--
+-- 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;
index fe217c6a2c10c48cd30b42319a395ae7beb7441e..4594a08eadb6d019c9fdbe985793eaf9d94f4570 100644 (file)
@@ -199,12 +199,19 @@ PLy_exec_function(FunctionCallInfo fcinfo, PLyProcedure *proc)
                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,
@@ -672,7 +679,8 @@ plpython_return_error_callback(void *arg)
 {
        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");
 }
 
index 32d23ae5b6d0883fd1d29bdeae6016087bc7ac95..695de305838c03472cca5762d5923d0ccde78974 100644 (file)
@@ -389,8 +389,14 @@ plpython_error_callback(void *arg)
        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
index faa4977463a2796f8e147b658884f3aa6a9a1641..b7c24e356f550b443047d5b0c1a2807cb0d97b81 100644 (file)
@@ -189,6 +189,7 @@ PLy_procedure_create(HeapTuple procTup, Oid fn_oid, bool is_trigger)
                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;
@@ -206,9 +207,9 @@ PLy_procedure_create(HeapTuple procTup, Oid fn_oid, bool is_trigger)
 
                /*
                 * 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;
index cd1b87fdc3cadfef3d654f6ae22301ddf70f7b6d..8968b5c92e5a56e1da90deef15d37e2ba0f80ebc 100644 (file)
@@ -30,7 +30,8 @@ typedef struct PLyProcedure
        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 */
diff --git a/src/pl/plpython/sql/plpython_call.sql b/src/pl/plpython/sql/plpython_call.sql
new file mode 100644 (file)
index 0000000..3fb74de
--- /dev/null
@@ -0,0 +1,41 @@
+--
+-- 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;
index b8971d3cc8fd4e163b70318112b86a20e478bf50..6a92a9b6aa747b4cbe32b008ecc30e6cc7ebc9de 100644 (file)
@@ -28,7 +28,7 @@ DATA = pltcl.control pltcl--1.0.sql pltcl--unpackaged--1.0.sql \
        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
diff --git a/src/pl/tcl/expected/pltcl_call.out b/src/pl/tcl/expected/pltcl_call.out
new file mode 100644 (file)
index 0000000..7221a37
--- /dev/null
@@ -0,0 +1,29 @@
+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;
index 6d97ddc99bd5f3277b5fd44af9b3e914cdf4fb47..e0792d93e1c7d751b6824f6f54ecff1d40e54709 100644 (file)
@@ -146,6 +146,7 @@ typedef struct pltcl_proc_desc
        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 */
@@ -968,7 +969,7 @@ pltcl_func_handler(PG_FUNCTION_ARGS, pltcl_call_state *call_state,
                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,
@@ -1026,11 +1027,13 @@ pltcl_func_handler(PG_FUNCTION_ARGS, pltcl_call_state *call_state,
                                                                           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;
 }
@@ -1506,7 +1509,9 @@ compile_pltcl_function(Oid fn_oid, Oid tgreloid,
                 * 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;
 
@@ -2199,7 +2204,7 @@ pltcl_returnnext(ClientData cdata, Tcl_Interp *interp,
                                tuplestore_puttuple(call_state->tuple_store, tuple);
                        }
                }
-               else
+               else if (!prodesc->fn_is_procedure)
                {
                        Datum           retval;
                        bool            isNull = false;
diff --git a/src/pl/tcl/sql/pltcl_call.sql b/src/pl/tcl/sql/pltcl_call.sql
new file mode 100644 (file)
index 0000000..ef1f540
--- /dev/null
@@ -0,0 +1,36 @@
+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;
diff --git a/src/test/regress/expected/create_procedure.out b/src/test/regress/expected/create_procedure.out
new file mode 100644 (file)
index 0000000..5538ef2
--- /dev/null
@@ -0,0 +1,92 @@
+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;
index 1fdadbc9ef6324716012ac25425d5db3543a96aa..bfd9d54c11939d704ce4e949a483e821ceb0a10b 100644 (file)
@@ -29,6 +29,7 @@ CREATE DOMAIN addr_nsp.gendomain AS int4 CONSTRAINT domconstr CHECK (value > 0);
 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;
@@ -88,7 +89,7 @@ BEGIN
                ('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'),
@@ -171,6 +172,12 @@ WARNING:  error for function,{addr_nsp,zwei},{}: function addr_nsp.zwei() does n
 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
@@ -371,6 +378,7 @@ WITH objects (type, name, args) AS (VALUES
                                ('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}', '{}'),
@@ -431,6 +439,7 @@ SELECT (pg_identify_object(addr1.classid, addr1.objid, addr1.objsubid)).*,
  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
@@ -469,7 +478,7 @@ SELECT (pg_identify_object(addr1.classid, addr1.objid, addr1.objsubid)).*,
  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
@@ -480,6 +489,6 @@ NOTICE:  drop cascades to 4 other objects
 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;
index bb3532676bd25bbdf1bd025ccffa041d68a37d0c..d6e5bc335369ca12c121a7fafc700188922b388d 100644 (file)
@@ -6040,3 +6040,44 @@ END; $$ LANGUAGE plpgsql;
 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;
index 91cfb743b63633b4ac9e73bd5821203f2963bab2..66e35a6a5c2d1947e5dc108f34e85842647c7ee8 100644 (file)
@@ -915,10 +915,10 @@ select dfunc();
 
 -- 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);
@@ -1083,10 +1083,10 @@ $$ select array_upper($1, 1) $$ language sql;
 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[]);
index 771971a095fd831d41ffbefa365b8c672a8f6c20..e6994f0490530c0ecb5e65e46678861908384dbc 100644 (file)
@@ -651,13 +651,25 @@ GRANT USAGE ON LANGUAGE sql TO regress_user2; -- fail
 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;
@@ -671,9 +683,20 @@ SELECT testfunc1(5), testfunc2(5); -- ok
 
 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
@@ -689,8 +712,19 @@ SELECT testfunc1(5); -- 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
@@ -1537,22 +1571,54 @@ SELECT has_schema_privilege('regress_user2', 'testns5', 'CREATE'); -- no
 
 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
@@ -1631,12 +1697,26 @@ SELECT has_table_privilege('regress_user1', 'testns.t2', 'SELECT'); -- false
 (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 
@@ -1644,9 +1724,47 @@ SELECT has_function_privilege('regress_user1', 'testns.testfunc(int)', 'EXECUTE'
  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 -
@@ -1729,8 +1847,10 @@ drop table dep_priv_test;
 -- 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;
index 892a214f2f3c89d0c22bcb436724b397ec34ae6c..e224977791e1225d85968ce74dbdf4428544a684 100644 (file)
@@ -53,7 +53,7 @@ test: copy copyselect copydml
 # ----------
 # 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
 
index 15a1f861a9405b72f66c8bcaf4ecdfc7b31751d9..9fc5f1a268818ee43b7851a9684a14d0ca12213b 100644 (file)
@@ -63,6 +63,7 @@ test: copyselect
 test: copydml
 test: create_misc
 test: create_operator
+test: create_procedure
 test: create_index
 test: create_view
 test: create_aggregate
diff --git a/src/test/regress/sql/create_procedure.sql b/src/test/regress/sql/create_procedure.sql
new file mode 100644 (file)
index 0000000..f09ba2a
--- /dev/null
@@ -0,0 +1,79 @@
+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;
index 63821b8008b94f4fb1729f00204bb571f7a10ed1..55faa71edfb87ffd10e03895d0bced9223c4744c 100644 (file)
@@ -32,6 +32,7 @@ CREATE DOMAIN addr_nsp.gendomain AS int4 CONSTRAINT domconstr CHECK (value > 0);
 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;
@@ -81,7 +82,7 @@ BEGIN
                ('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'),
@@ -147,6 +148,7 @@ WITH objects (type, name, args) AS (VALUES
                                ('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}', '{}'),
index 6620ea61729920edd414ef79651731c82d3e4f70..1c355132b77fcae683e620ba1a7c61b5e354a770 100644 (file)
@@ -4820,3 +4820,52 @@ BEGIN
   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;
index a900ba2f8495f00f5660344ec70a87e0315d7d73..ea8dd028cd005ed2226fd928c438d7d54cbe59a0 100644 (file)
@@ -442,12 +442,21 @@ SET SESSION AUTHORIZATION regress_user1;
 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;'
@@ -457,16 +466,24 @@ GRANT EXECUTE ON FUNCTION testfunc4(boolean) TO regress_user3;
 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 -
 
@@ -931,17 +948,29 @@ SELECT has_schema_privilege('regress_user2', 'testns5', 'CREATE'); -- no
 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;
 
@@ -995,12 +1024,28 @@ SELECT has_table_privilege('regress_user1', 'testns.t1', 'SELECT'); -- false
 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;
@@ -1064,8 +1109,10 @@ drop table dep_priv_test;
 
 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;