1CREATE RULE(7)           PostgreSQL 16.1 Documentation          CREATE RULE(7)
2
3
4

NAME

6       CREATE_RULE - define a new rewrite rule
7

SYNOPSIS

9       CREATE [ OR REPLACE ] RULE name AS ON event
10           TO table_name [ WHERE condition ]
11           DO [ ALSO | INSTEAD ] { NOTHING | command | ( command ; command ... ) }
12
13       where event can be one of:
14
15           SELECT | INSERT | UPDATE | DELETE
16

DESCRIPTION

18       CREATE RULE defines a new rule applying to a specified table or view.
19       CREATE OR REPLACE RULE will either create a new rule, or replace an
20       existing rule of the same name for the same table.
21
22       The PostgreSQL rule system allows one to define an alternative action
23       to be performed on insertions, updates, or deletions in database
24       tables. Roughly speaking, a rule causes additional commands to be
25       executed when a given command on a given table is executed.
26       Alternatively, an INSTEAD rule can replace a given command by another,
27       or cause a command not to be executed at all. Rules are used to
28       implement SQL views as well. It is important to realize that a rule is
29       really a command transformation mechanism, or command macro. The
30       transformation happens before the execution of the command starts. If
31       you actually want an operation that fires independently for each
32       physical row, you probably want to use a trigger, not a rule. More
33       information about the rules system is in Chapter 41.
34
35       Presently, ON SELECT rules can only be attached to views. Such a rule
36       must be named "_RETURN", must be an unconditional INSTEAD rule, and
37       must have an action that consists of a single SELECT command. This
38       command defines the visible contents of the view. (The view itself is
39       basically a dummy table with no storage.) It's best to regard such a
40       rule as an implementation detail. While a view can be redefined via
41       CREATE OR REPLACE RULE "_RETURN" AS ..., it's better style to use
42       CREATE OR REPLACE VIEW.
43
44       You can create the illusion of an updatable view by defining ON INSERT,
45       ON UPDATE, and ON DELETE rules (or any subset of those that's
46       sufficient for your purposes) to replace update actions on the view
47       with appropriate updates on other tables. If you want to support INSERT
48       RETURNING and so on, then be sure to put a suitable RETURNING clause
49       into each of these rules.
50
51       There is a catch if you try to use conditional rules for complex view
52       updates: there must be an unconditional INSTEAD rule for each action
53       you wish to allow on the view. If the rule is conditional, or is not
54       INSTEAD, then the system will still reject attempts to perform the
55       update action, because it thinks it might end up trying to perform the
56       action on the dummy table of the view in some cases. If you want to
57       handle all the useful cases in conditional rules, add an unconditional
58       DO INSTEAD NOTHING rule to ensure that the system understands it will
59       never be called on to update the dummy table. Then make the conditional
60       rules non-INSTEAD; in the cases where they are applied, they add to the
61       default INSTEAD NOTHING action. (This method does not currently work to
62       support RETURNING queries, however.)
63
64           Note
65           A view that is simple enough to be automatically updatable (see
66           CREATE VIEW (CREATE_VIEW(7))) does not require a user-created rule
67           in order to be updatable. While you can create an explicit rule
68           anyway, the automatic update transformation will generally
69           outperform an explicit rule.
70
71           Another alternative worth considering is to use INSTEAD OF triggers
72           (see CREATE TRIGGER (CREATE_TRIGGER(7))) in place of rules.
73

PARAMETERS

75       name
76           The name of a rule to create. This must be distinct from the name
77           of any other rule for the same table. Multiple rules on the same
78           table and same event type are applied in alphabetical name order.
79
80       event
81           The event is one of SELECT, INSERT, UPDATE, or DELETE. Note that an
82           INSERT containing an ON CONFLICT clause cannot be used on tables
83           that have either INSERT or UPDATE rules. Consider using an
84           updatable view instead.
85
86       table_name
87           The name (optionally schema-qualified) of the table or view the
88           rule applies to.
89
90       condition
91           Any SQL conditional expression (returning boolean). The condition
92           expression cannot refer to any tables except NEW and OLD, and
93           cannot contain aggregate functions.
94
95       INSTEAD
96           INSTEAD indicates that the commands should be executed instead of
97           the original command.
98
99       ALSO
100           ALSO indicates that the commands should be executed in addition to
101           the original command.
102
103           If neither ALSO nor INSTEAD is specified, ALSO is the default.
104
105       command
106           The command or commands that make up the rule action. Valid
107           commands are SELECT, INSERT, UPDATE, DELETE, or NOTIFY.
108
109       Within condition and command, the special table names NEW and OLD can
110       be used to refer to values in the referenced table.  NEW is valid in ON
111       INSERT and ON UPDATE rules to refer to the new row being inserted or
112       updated.  OLD is valid in ON UPDATE and ON DELETE rules to refer to the
113       existing row being updated or deleted.
114

NOTES

116       You must be the owner of a table to create or change rules for it.
117
118       In a rule for INSERT, UPDATE, or DELETE on a view, you can add a
119       RETURNING clause that emits the view's columns. This clause will be
120       used to compute the outputs if the rule is triggered by an INSERT
121       RETURNING, UPDATE RETURNING, or DELETE RETURNING command respectively.
122       When the rule is triggered by a command without RETURNING, the rule's
123       RETURNING clause will be ignored. The current implementation allows
124       only unconditional INSTEAD rules to contain RETURNING; furthermore
125       there can be at most one RETURNING clause among all the rules for the
126       same event. (This ensures that there is only one candidate RETURNING
127       clause to be used to compute the results.)  RETURNING queries on the
128       view will be rejected if there is no RETURNING clause in any available
129       rule.
130
131       It is very important to take care to avoid circular rules. For example,
132       though each of the following two rule definitions are accepted by
133       PostgreSQL, the SELECT command would cause PostgreSQL to report an
134       error because of recursive expansion of a rule:
135
136           CREATE RULE "_RETURN" AS
137               ON SELECT TO t1
138               DO INSTEAD
139                   SELECT * FROM t2;
140
141           CREATE RULE "_RETURN" AS
142               ON SELECT TO t2
143               DO INSTEAD
144                   SELECT * FROM t1;
145
146           SELECT * FROM t1;
147
148       Presently, if a rule action contains a NOTIFY command, the NOTIFY
149       command will be executed unconditionally, that is, the NOTIFY will be
150       issued even if there are not any rows that the rule should apply to.
151       For example, in:
152
153           CREATE RULE notify_me AS ON UPDATE TO mytable DO ALSO NOTIFY mytable;
154
155           UPDATE mytable SET name = 'foo' WHERE id = 42;
156
157       one NOTIFY event will be sent during the UPDATE, whether or not there
158       are any rows that match the condition id = 42. This is an
159       implementation restriction that might be fixed in future releases.
160

COMPATIBILITY

162       CREATE RULE is a PostgreSQL language extension, as is the entire query
163       rewrite system.
164

SEE ALSO

166       ALTER RULE (ALTER_RULE(7)), DROP RULE (DROP_RULE(7))
167
168
169
170PostgreSQL 16.1                      2023                       CREATE RULE(7)
Impressum