1CREATE RULE() SQL Commands CREATE RULE()
2
3
4
6 CREATE RULE - define a new rewrite rule
7
8
10 CREATE [ OR REPLACE ] RULE name AS ON event
11 TO table [ WHERE condition ]
12 DO [ ALSO | INSTEAD ] { NOTHING | command | ( command ; command ... ) }
13
14
16 CREATE RULE defines a new rule applying to a specified table or view.
17 CREATE OR REPLACE RULE will either create a new rule, or replace an
18 existing rule of the same name for the same table.
19
20 The PostgreSQL rule system allows one to define an alternate action to
21 be performed on insertions, updates, or deletions in database tables.
22 Roughly speaking, a rule causes additional commands to be executed when
23 a given command on a given table is executed. Alternatively, an INSTEAD
24 rule can replace a given command by another, or cause a command not to
25 be executed at all. Rules are used to implement table views as well. It
26 is important to realize that a rule is really a command transformation
27 mechanism, or command macro. The transformation happens before the exe‐
28 cution of the commands starts. If you actually want an operation that
29 fires independently for each physical row, you probably want to use a
30 trigger, not a rule. More information about the rules system is in in
31 the documentation.
32
33 Presently, ON SELECT rules must be unconditional INSTEAD rules and must
34 have actions that consist of a single SELECT command. Thus, an ON
35 SELECT rule effectively turns the table into a view, whose visible con‐
36 tents are the rows returned by the rule's SELECT command rather than
37 whatever had been stored in the table (if anything). It is considered
38 better style to write a CREATE VIEW command than to create a real table
39 and define an ON SELECT rule for it.
40
41 You can create the illusion of an updatable view by defining ON INSERT,
42 ON UPDATE, and ON DELETE rules (or any subset of those that's suffi‐
43 cient for your purposes) to replace update actions on the view with
44 appropriate updates on other tables. If you want to support INSERT
45 RETURNING and so on, then be sure to put a suitable RETURNING clause
46 into each of these rules.
47
48 There is a catch if you try to use conditional rules for view updates:
49 there must be an unconditional INSTEAD rule for each action you wish to
50 allow on the view. If the rule is conditional, or is not INSTEAD, then
51 the system will still reject attempts to perform the update action,
52 because it thinks it might end up trying to perform the action on the
53 dummy table of the view in some cases. If you want to handle all the
54 useful cases in conditional rules, add an unconditional DO INSTEAD
55 NOTHING rule to ensure that the system understands it will never be
56 called on to update the dummy table. Then make the conditional rules
57 non-INSTEAD; in the cases where they are applied, they add to the
58 default INSTEAD NOTHING action. (This method does not currently work to
59 support RETURNING queries, however.)
60
62 name The name of a rule to create. This must be distinct from the
63 name of any other rule for the same table. Multiple rules on the
64 same table and same event type are applied in alphabetical name
65 order.
66
67 event The event is one of SELECT, INSERT, UPDATE, or DELETE.
68
69 table The name (optionally schema-qualified) of the table or view the
70 rule applies to.
71
72 condition
73 Any SQL conditional expression (returning boolean). The condi‐
74 tion expression may not refer to any tables except NEW and OLD,
75 and may not contain aggregate functions.
76
77 INSTEAD
78 INSTEAD indicates that the commands should be executed instead
79 of the original command.
80
81 ALSO ALSO indicates that the commands should be executed in addition
82 to the original command.
83
84 If neither ALSO nor INSTEAD is specified, ALSO is the default.
85
86 command
87 The command or commands that make up the rule action. Valid com‐
88 mands are SELECT, INSERT, UPDATE, DELETE, or NOTIFY.
89
90 Within condition and command, the special table names NEW and OLD may
91 be used to refer to values in the referenced table. NEW is valid in ON
92 INSERT and ON UPDATE rules to refer to the new row being inserted or
93 updated. OLD is valid in ON UPDATE and ON DELETE rules to refer to the
94 existing row being updated or deleted.
95
97 You must be the owner of a table to create or change rules for it.
98
99 In a rule for INSERT, UPDATE, or DELETE on a view, you can add a
100 RETURNING clause that emits the view's columns. This clause will be
101 used to compute the outputs if the rule is triggered by an INSERT
102 RETURNING, UPDATE RETURNING, or DELETE RETURNING command respectively.
103 When the rule is triggered by a command without RETURNING, the rule's
104 RETURNING clause will be ignored. The current implementation allows
105 only unconditional INSTEAD rules to contain RETURNING; furthermore
106 there can be at most one RETURNING clause among all the rules for the
107 same event. (This ensures that there is only one candidate RETURNING
108 clause to be used to compute the results.) RETURNING queries on the
109 view will be rejected if there is no RETURNING clause in any available
110 rule.
111
112 It is very important to take care to avoid circular rules. For example,
113 though each of the following two rule definitions are accepted by Post‐
114 greSQL, the SELECT command would cause PostgreSQL to report an error
115 because of recursive expansion of a rule:
116
117 CREATE RULE "_RETURN" AS
118 ON SELECT TO t1
119 DO INSTEAD
120 SELECT * FROM t2;
121
122 CREATE RULE "_RETURN" AS
123 ON SELECT TO t2
124 DO INSTEAD
125 SELECT * FROM t1;
126
127 SELECT * FROM t1;
128
129
130 Presently, if a rule action contains a NOTIFY command, the NOTIFY com‐
131 mand will be executed unconditionally, that is, the NOTIFY will be
132 issued even if there are not any rows that the rule should apply to.
133 For example, in
134
135 CREATE RULE notify_me AS ON UPDATE TO mytable DO ALSO NOTIFY mytable;
136
137 UPDATE mytable SET name = 'foo' WHERE id = 42;
138
139 one NOTIFY event will be sent during the UPDATE, whether or not there
140 are any rows that match the condition id = 42. This is an implementa‐
141 tion restriction that may be fixed in future releases.
142
144 CREATE RULE is a PostgreSQL language extension, as is the entire query
145 rewrite system.
146
147
148
149SQL - Language Statements 2008-06-08 CREATE RULE()