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
|
'\" t
.\" Title: CREATE PROCEDURE
.\" Author: The PostgreSQL Global Development Group
.\" Generator: DocBook XSL Stylesheets vsnapshot <http://docbook.sf.net/>
.\" Date: 2024
.\" Manual: PostgreSQL 16.2 Documentation
.\" Source: PostgreSQL 16.2
.\" Language: English
.\"
.TH "CREATE PROCEDURE" "7" "2024" "PostgreSQL 16.2" "PostgreSQL 16.2 Documentation"
.\" -----------------------------------------------------------------
.\" * Define some portability stuff
.\" -----------------------------------------------------------------
.\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
.\" http://bugs.debian.org/507673
.\" http://lists.gnu.org/archive/html/groff/2009-02/msg00013.html
.\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
.ie \n(.g .ds Aq \(aq
.el .ds Aq '
.\" -----------------------------------------------------------------
.\" * set default formatting
.\" -----------------------------------------------------------------
.\" disable hyphenation
.nh
.\" disable justification (adjust text to left margin only)
.ad l
.\" -----------------------------------------------------------------
.\" * MAIN CONTENT STARTS HERE *
.\" -----------------------------------------------------------------
.SH "NAME"
CREATE_PROCEDURE \- define a new procedure
.SH "SYNOPSIS"
.sp
.nf
CREATE [ OR REPLACE ] PROCEDURE
\fIname\fR ( [ [ \fIargmode\fR ] [ \fIargname\fR ] \fIargtype\fR [ { DEFAULT | = } \fIdefault_expr\fR ] [, \&.\&.\&.] ] )
{ LANGUAGE \fIlang_name\fR
| TRANSFORM { FOR TYPE \fItype_name\fR } [, \&.\&.\&. ]
| [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
| SET \fIconfiguration_parameter\fR { TO \fIvalue\fR | = \fIvalue\fR | FROM CURRENT }
| AS \*(Aq\fIdefinition\fR\*(Aq
| AS \*(Aq\fIobj_file\fR\*(Aq, \*(Aq\fIlink_symbol\fR\*(Aq
| \fIsql_body\fR
} \&.\&.\&.
.fi
.SH "DESCRIPTION"
.PP
\fBCREATE PROCEDURE\fR
defines a new procedure\&.
\fBCREATE OR REPLACE PROCEDURE\fR
will either create a new procedure, or replace an existing definition\&. To be able to define a procedure, the user must have the
USAGE
privilege on the language\&.
.PP
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
overloading)\&.
.PP
To replace the current definition of an existing procedure, use
\fBCREATE OR REPLACE PROCEDURE\fR\&. 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)\&.
.PP
When
\fBCREATE OR REPLACE PROCEDURE\fR
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)\&.
.PP
The user that creates the procedure becomes the owner of the procedure\&.
.PP
To be able to create a procedure, you must have
USAGE
privilege on the argument types\&.
.PP
Refer to
Section\ \&38.4
for further information on writing procedures\&.
.SH "PARAMETERS"
.PP
\fIname\fR
.RS 4
The name (optionally schema\-qualified) of the procedure to create\&.
.RE
.PP
\fIargmode\fR
.RS 4
The mode of an argument:
IN,
OUT,
INOUT, or
VARIADIC\&. If omitted, the default is
IN\&.
.RE
.PP
\fIargname\fR
.RS 4
The name of an argument\&.
.RE
.PP
\fIargtype\fR
.RS 4
The data type(s) of the procedure\*(Aqs 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\&.
.sp
Depending on the implementation language it might also be allowed to specify
\(lqpseudo\-types\(rq
such as
cstring\&. Pseudo\-types indicate that the actual argument type is either incompletely specified, or outside the set of ordinary SQL data types\&.
.sp
The type of a column is referenced by writing
\fItable_name\fR\&.\fIcolumn_name\fR%TYPE\&. Using this feature can sometimes help make a procedure independent of changes to the definition of a table\&.
.RE
.PP
\fIdefault_expr\fR
.RS 4
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\&.
.RE
.PP
\fIlang_name\fR
.RS 4
The name of the language that the procedure is implemented in\&. It can be
sql,
c,
internal, or the name of a user\-defined procedural language, e\&.g\&.,
plpgsql\&. The default is
sql
if
\fIsql_body\fR
is specified\&. Enclosing the name in single quotes is deprecated and requires matching case\&.
.RE
.PP
TRANSFORM { FOR TYPE \fItype_name\fR } [, \&.\&.\&. ] }
.RS 4
Lists which transforms a call to the procedure should apply\&. Transforms convert between SQL types and language\-specific data types; see
CREATE TRANSFORM (\fBCREATE_TRANSFORM\fR(7))\&. Procedural language implementations usually have hardcoded knowledge of the built\-in types, so those don\*(Aqt 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\&.
.RE
.PP
[EXTERNAL] SECURITY INVOKER
.br
[EXTERNAL] SECURITY DEFINER
.RS 4
SECURITY INVOKER
indicates that the procedure is to be executed with the privileges of the user that calls it\&. That is the default\&.
SECURITY DEFINER
specifies that the procedure is to be executed with the privileges of the user that owns it\&.
.sp
The key word
EXTERNAL
is allowed for SQL conformance, but it is optional since, unlike in SQL, this feature applies to all procedures not only external ones\&.
.sp
A
SECURITY DEFINER
procedure cannot execute transaction control statements (for example,
\fBCOMMIT\fR
and
\fBROLLBACK\fR, depending on the language)\&.
.RE
.PP
\fIconfiguration_parameter\fR
.br
\fIvalue\fR
.RS 4
The
SET
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\&.
SET FROM CURRENT
saves the value of the parameter that is current when
\fBCREATE PROCEDURE\fR
is executed as the value to be applied when the procedure is entered\&.
.sp
If a
SET
clause is attached to a procedure, then the effects of a
\fBSET LOCAL\fR
command executed inside the procedure for the same variable are restricted to the procedure: the configuration parameter\*(Aqs prior value is still restored at procedure exit\&. However, an ordinary
\fBSET\fR
command (without
LOCAL) overrides the
SET
clause, much as it would do for a previous
\fBSET LOCAL\fR
command: the effects of such a command will persist after procedure exit, unless the current transaction is rolled back\&.
.sp
If a
SET
clause is attached to a procedure, then that procedure cannot execute transaction control statements (for example,
\fBCOMMIT\fR
and
\fBROLLBACK\fR, depending on the language)\&.
.sp
See
\fBSET\fR(7)
and
Chapter\ \&20
for more information about allowed parameter names and values\&.
.RE
.PP
\fIdefinition\fR
.RS 4
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\&.
.sp
It is often helpful to use dollar quoting (see
Section\ \&4.1.2.4) 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\&.
.RE
.PP
\fIobj_file\fR, \fIlink_symbol\fR
.RS 4
This form of the
AS
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
\fIobj_file\fR
is the name of the shared library file containing the compiled C procedure, and is interpreted as for the
\fBLOAD\fR
command\&. The string
\fIlink_symbol\fR
is the procedure\*(Aqs 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\&.
.sp
When repeated
\fBCREATE PROCEDURE\fR
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\&.
.RE
.PP
\fIsql_body\fR
.RS 4
The body of a
LANGUAGE SQL
procedure\&. This should be a block
.sp
.if n \{\
.RS 4
.\}
.nf
BEGIN ATOMIC
\fIstatement\fR;
\fIstatement\fR;
\&.\&.\&.
\fIstatement\fR;
END
.fi
.if n \{\
.RE
.\}
.sp
This is similar to writing the text of the procedure body as a string constant (see
\fIdefinition\fR
above), but there are some differences: This form only works for
LANGUAGE SQL, the string constant form works for all languages\&. This form is parsed at procedure definition time, the string constant form is parsed at execution time; therefore this form cannot support polymorphic argument types and other constructs that are not resolvable at procedure definition time\&. This form tracks dependencies between the procedure and objects used in the procedure body, so
DROP \&.\&.\&. CASCADE
will work correctly, whereas the form using string literals may leave dangling procedures\&. Finally, this form is more compatible with the SQL standard and other SQL implementations\&.
.RE
.SH "NOTES"
.PP
See
CREATE FUNCTION (\fBCREATE_FUNCTION\fR(7))
for more details on function creation that also apply to procedures\&.
.PP
Use
\fBCALL\fR(7)
to execute a procedure\&.
.SH "EXAMPLES"
.PP
.if n \{\
.RS 4
.\}
.nf
CREATE PROCEDURE insert_data(a integer, b integer)
LANGUAGE SQL
AS $$
INSERT INTO tbl VALUES (a);
INSERT INTO tbl VALUES (b);
$$;
.fi
.if n \{\
.RE
.\}
.sp
or
.sp
.if n \{\
.RS 4
.\}
.nf
CREATE PROCEDURE insert_data(a integer, b integer)
LANGUAGE SQL
BEGIN ATOMIC
INSERT INTO tbl VALUES (a);
INSERT INTO tbl VALUES (b);
END;
.fi
.if n \{\
.RE
.\}
.sp
and call like this:
.sp
.if n \{\
.RS 4
.\}
.nf
CALL insert_data(1, 2);
.fi
.if n \{\
.RE
.\}
.SH "COMPATIBILITY"
.PP
A
\fBCREATE PROCEDURE\fR
command is defined in the SQL standard\&. The
PostgreSQL
implementation can be used in a compatible way but has many extensions\&. For details see also
CREATE FUNCTION (\fBCREATE_FUNCTION\fR(7))\&.
.SH "SEE ALSO"
ALTER PROCEDURE (\fBALTER_PROCEDURE\fR(7)), DROP PROCEDURE (\fBDROP_PROCEDURE\fR(7)), \fBCALL\fR(7), CREATE FUNCTION (\fBCREATE_FUNCTION\fR(7))
|