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
|
'\" t
.\" Title: CREATE RULE
.\" Author: The PostgreSQL Global Development Group
.\" Generator: DocBook XSL Stylesheets vsnapshot <http://docbook.sf.net/>
.\" Date: 2023
.\" Manual: PostgreSQL 15.5 Documentation
.\" Source: PostgreSQL 15.5
.\" Language: English
.\"
.TH "CREATE RULE" "7" "2023" "PostgreSQL 15.5" "PostgreSQL 15.5 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_RULE \- define a new rewrite rule
.SH "SYNOPSIS"
.sp
.nf
CREATE [ OR REPLACE ] RULE \fIname\fR AS ON \fIevent\fR
TO \fItable_name\fR [ WHERE \fIcondition\fR ]
DO [ ALSO | INSTEAD ] { NOTHING | \fIcommand\fR | ( \fIcommand\fR ; \fIcommand\fR \&.\&.\&. ) }
where \fIevent\fR can be one of:
SELECT | INSERT | UPDATE | DELETE
.fi
.SH "DESCRIPTION"
.PP
\fBCREATE RULE\fR
defines a new rule applying to a specified table or view\&.
\fBCREATE OR REPLACE RULE\fR
will either create a new rule, or replace an existing rule of the same name for the same table\&.
.PP
The
PostgreSQL
rule system allows one to define an alternative action to be performed on insertions, updates, or deletions in database tables\&. Roughly speaking, a rule causes additional commands to be executed when a given command on a given table is executed\&. Alternatively, an
INSTEAD
rule can replace a given command by another, or cause a command not to be executed at all\&. Rules are used to implement SQL views as well\&. It is important to realize that a rule is really a command transformation mechanism, or command macro\&. The transformation happens before the execution of the command starts\&. If you actually want an operation that fires independently for each physical row, you probably want to use a trigger, not a rule\&. More information about the rules system is in
Chapter\ \&41\&.
.PP
Presently,
ON SELECT
rules can only be attached to views\&. (Attaching one to a table converts the table into a view\&.) Such a rule must be named
"_RETURN", must be an unconditional
INSTEAD
rule, and must have an action that consists of a single
\fBSELECT\fR
command\&. This command defines the visible contents of the view\&. (The view itself is basically a dummy table with no storage\&.) It\*(Aqs best to regard such a rule as an implementation detail\&. While a view can be redefined via
CREATE OR REPLACE RULE "_RETURN" AS \&.\&.\&., it\*(Aqs better style to use
CREATE OR REPLACE VIEW\&.
.PP
You can create the illusion of an updatable view by defining
ON INSERT,
ON UPDATE, and
ON DELETE
rules (or any subset of those that\*(Aqs sufficient for your purposes) to replace update actions on the view with appropriate updates on other tables\&. If you want to support
\fBINSERT RETURNING\fR
and so on, then be sure to put a suitable
RETURNING
clause into each of these rules\&.
.PP
There is a catch if you try to use conditional rules for complex view updates: there
\fImust\fR
be an unconditional
INSTEAD
rule for each action you wish to allow on the view\&. If the rule is conditional, or is not
INSTEAD, then the system will still reject attempts to perform the update action, because it thinks it might end up trying to perform the action on the dummy table of the view in some cases\&. If you want to handle all the useful cases in conditional rules, add an unconditional
DO INSTEAD NOTHING
rule to ensure that the system understands it will never be called on to update the dummy table\&. Then make the conditional rules non\-INSTEAD; in the cases where they are applied, they add to the default
INSTEAD NOTHING
action\&. (This method does not currently work to support
RETURNING
queries, however\&.)
.if n \{\
.sp
.\}
.RS 4
.it 1 an-trap
.nr an-no-space-flag 1
.nr an-break-flag 1
.br
.ps +1
\fBNote\fR
.ps -1
.br
.PP
A view that is simple enough to be automatically updatable (see
CREATE VIEW (\fBCREATE_VIEW\fR(7))) does not require a user\-created rule in order to be updatable\&. While you can create an explicit rule anyway, the automatic update transformation will generally outperform an explicit rule\&.
.PP
Another alternative worth considering is to use
INSTEAD OF
triggers (see
CREATE TRIGGER (\fBCREATE_TRIGGER\fR(7))) in place of rules\&.
.sp .5v
.RE
.SH "PARAMETERS"
.PP
\fIname\fR
.RS 4
The name of a rule to create\&. This must be distinct from the name of any other rule for the same table\&. Multiple rules on the same table and same event type are applied in alphabetical name order\&.
.RE
.PP
\fIevent\fR
.RS 4
The event is one of
SELECT,
INSERT,
UPDATE, or
DELETE\&. Note that an
\fBINSERT\fR
containing an
ON CONFLICT
clause cannot be used on tables that have either
INSERT
or
UPDATE
rules\&. Consider using an updatable view instead\&.
.RE
.PP
\fItable_name\fR
.RS 4
The name (optionally schema\-qualified) of the table or view the rule applies to\&.
.RE
.PP
\fIcondition\fR
.RS 4
Any
SQL
conditional expression (returning
boolean)\&. The condition expression cannot refer to any tables except
NEW
and
OLD, and cannot contain aggregate functions\&.
.RE
.PP
\fBINSTEAD\fR
.RS 4
INSTEAD
indicates that the commands should be executed
\fIinstead of\fR
the original command\&.
.RE
.PP
\fBALSO\fR
.RS 4
ALSO
indicates that the commands should be executed
\fIin addition to\fR
the original command\&.
.sp
If neither
ALSO
nor
INSTEAD
is specified,
ALSO
is the default\&.
.RE
.PP
\fIcommand\fR
.RS 4
The command or commands that make up the rule action\&. Valid commands are
\fBSELECT\fR,
\fBINSERT\fR,
\fBUPDATE\fR,
\fBDELETE\fR, or
\fBNOTIFY\fR\&.
.RE
.PP
Within
\fIcondition\fR
and
\fIcommand\fR, the special table names
NEW
and
OLD
can be used to refer to values in the referenced table\&.
NEW
is valid in
ON INSERT
and
ON UPDATE
rules to refer to the new row being inserted or updated\&.
OLD
is valid in
ON UPDATE
and
ON DELETE
rules to refer to the existing row being updated or deleted\&.
.SH "NOTES"
.PP
You must be the owner of a table to create or change rules for it\&.
.PP
In a rule for
INSERT,
UPDATE, or
DELETE
on a view, you can add a
RETURNING
clause that emits the view\*(Aqs columns\&. This clause will be used to compute the outputs if the rule is triggered by an
\fBINSERT RETURNING\fR,
\fBUPDATE RETURNING\fR, or
\fBDELETE RETURNING\fR
command respectively\&. When the rule is triggered by a command without
RETURNING, the rule\*(Aqs
RETURNING
clause will be ignored\&. The current implementation allows only unconditional
INSTEAD
rules to contain
RETURNING; furthermore there can be at most one
RETURNING
clause among all the rules for the same event\&. (This ensures that there is only one candidate
RETURNING
clause to be used to compute the results\&.)
RETURNING
queries on the view will be rejected if there is no
RETURNING
clause in any available rule\&.
.PP
It is very important to take care to avoid circular rules\&. For example, though each of the following two rule definitions are accepted by
PostgreSQL, the
\fBSELECT\fR
command would cause
PostgreSQL
to report an error because of recursive expansion of a rule:
.sp
.if n \{\
.RS 4
.\}
.nf
CREATE RULE "_RETURN" AS
ON SELECT TO t1
DO INSTEAD
SELECT * FROM t2;
CREATE RULE "_RETURN" AS
ON SELECT TO t2
DO INSTEAD
SELECT * FROM t1;
SELECT * FROM t1;
.fi
.if n \{\
.RE
.\}
.PP
Presently, if a rule action contains a
\fBNOTIFY\fR
command, the
\fBNOTIFY\fR
command will be executed unconditionally, that is, the
\fBNOTIFY\fR
will be issued even if there are not any rows that the rule should apply to\&. For example, in:
.sp
.if n \{\
.RS 4
.\}
.nf
CREATE RULE notify_me AS ON UPDATE TO mytable DO ALSO NOTIFY mytable;
UPDATE mytable SET name = \*(Aqfoo\*(Aq WHERE id = 42;
.fi
.if n \{\
.RE
.\}
.sp
one
\fBNOTIFY\fR
event will be sent during the
\fBUPDATE\fR, whether or not there are any rows that match the condition
id = 42\&. This is an implementation restriction that might be fixed in future releases\&.
.SH "COMPATIBILITY"
.PP
\fBCREATE RULE\fR
is a
PostgreSQL
language extension, as is the entire query rewrite system\&.
.SH "SEE ALSO"
ALTER RULE (\fBALTER_RULE\fR(7)), DROP RULE (\fBDROP_RULE\fR(7))
|