1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
|
<!--
doc/src/sgml/ref/create_procedure.sgml
PostgreSQL documentation
-->
<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>
<para>
Refer to <xref linkend="xproc"/> for further information on writing
procedures.
</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>,
<literal>INOUT</literal>, or <literal>VARIADIC</literal>. If omitted,
the default is <literal>IN</literal>. (<literal>OUT</literal>
arguments are currently not supported for procedures. Use
<literal>INOUT</literal> instead.)
</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>
<para>
A <literal>SECURITY DEFINER</literal> procedure cannot execute
transaction control statements (for example, <command>COMMIT</command>
and <command>ROLLBACK</command>, depending on the language).
</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>
If a <literal>SET</literal> clause is attached to a procedure, then
that procedure cannot execute transaction control statements (for
example, <command>COMMIT</command> and <command>ROLLBACK</command>,
depending on the language).
</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>
|