1CREATE RULE(7)           PostgreSQL 11.3 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 must be unconditional INSTEAD rules and must
36       have actions that consist of a single SELECT command. Thus, an ON
37       SELECT rule effectively turns the table into a view, whose visible
38       contents are the rows returned by the rule's SELECT command rather than
39       whatever had been stored in the table (if anything). It is considered
40       better style to write a CREATE VIEW command than to create a real table
41       and define an ON SELECT rule for it.
42
43       You can create the illusion of an updatable view by defining ON INSERT,
44       ON UPDATE, and ON DELETE rules (or any subset of those that's
45       sufficient for your purposes) to replace update actions on the view
46       with appropriate updates on other tables. If you want to support INSERT
47       RETURNING and so on, then be sure to put a suitable RETURNING clause
48       into each of these rules.
49
50       There is a catch if you try to use conditional rules for complex view
51       updates: there must be an unconditional INSTEAD rule for each action
52       you wish to allow on the view. If the rule is conditional, or is not
53       INSTEAD, then the system will still reject attempts to perform the
54       update action, because it thinks it might end up trying to perform the
55       action on the dummy table of the view in some cases. If you want to
56       handle all the useful cases in conditional rules, add an unconditional
57       DO INSTEAD NOTHING rule to ensure that the system understands it will
58       never be called on to update the dummy table. Then make the conditional
59       rules non-INSTEAD; in the cases where they are applied, they add to the
60       default INSTEAD NOTHING action. (This method does not currently work to
61       support RETURNING queries, however.)
62
63           Note
64           A view that is simple enough to be automatically updatable (see
65           CREATE VIEW (CREATE_VIEW(7))) does not require a user-created rule
66           in order to be updatable. While you can create an explicit rule
67           anyway, the automatic update transformation will generally
68           outperform an explicit rule.
69
70           Another alternative worth considering is to use INSTEAD OF triggers
71           (see CREATE TRIGGER (CREATE_TRIGGER(7))) in place of rules.
72

PARAMETERS

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

NOTES

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

COMPATIBILITY

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

SEE ALSO

165       ALTER RULE (ALTER_RULE(7)), DROP RULE (DROP_RULE(7))
166
167
168
169PostgreSQL 11.3                      2019                       CREATE RULE(7)
Impressum