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
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
|
<refentry id="SQL-CREATERULE">
<refmeta>
<refentrytitle>
CREATE RULE
</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>
CREATE RULE
</refname>
<refpurpose>
Defines a new rule
</refpurpose>
</refnamediv>
<refsynopsisdiv>
<refsynopsisdivinfo>
<date>1998-09-11</date>
</refsynopsisdivinfo>
<synopsis>
CREATE RULE <replaceable class="parameter">name</replaceable> AS ON <replaceable class="parameter">event</replaceable>
TO <replaceable class="parameter">object</replaceable> [ WHERE <replaceable class="parameter">condition</replaceable> ]
DO [ INSTEAD ] [ <replaceable class="parameter">action</replaceable> | NOTHING ]
</synopsis>
<refsect2 id="R2-SQL-CREATERULE-1">
<refsect2info>
<date>1998-09-11</date>
</refsect2info>
<title>
Inputs
</title>
<para>
<variablelist>
<varlistentry>
<term><replaceable class="parameter">name</replaceable></term>
<listitem>
<para>
The name of a rule to create.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">event</replaceable></term>
<listitem>
<para>
Event is one of <literal>select</literal>,
<literal>update</literal>, <literal>delete</literal>
or <literal>insert</literal>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">object</replaceable></term>
<listitem>
<para>
Object is either <replaceable class="parameter">table</replaceable>
or <replaceable class="parameter">table</replaceable>.<replaceable
class="parameter">column</replaceable>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">condition</replaceable></term>
<listitem>
<para>
Any SQL WHERE clause. <literal>new</literal> or
<literal>current</literal> can appear instead of an instance
variable whenever an instance variable is permissible in SQL.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">action</replaceable></term>
<listitem>
<para>
Any SQL statement. <literal>new</literal> or
<literal>current</literal> can appear instead of an instance
variable whenever an instance variable is permissible in SQL.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
<refsect2 id="R2-SQL-CREATERULE-2">
<refsect2info>
<date>1998-09-11</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term><computeroutput>
CREATE
</computeroutput></term>
<listitem>
<para>
Message returned if the rule is successfully created.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv>
<refsect1 id="R1-SQL-CREATERULE-1">
<refsect1info>
<date>1998-09-11</date>
</refsect1info>
<title>
Description
</title>
<para>
The semantics of a rule is that at the time an individual instance is
accessed, updated, inserted or deleted, there is a current instance (for
retrieves, updates and deletes) and a new instance (for updates and
appends). If the <replaceable class="parameter">event</replaceable>
specified in the ON clause and the
<replaceable class="parameter">condition</replaceable> specified in the
WHERE clause are true for the current instance, the
<replaceable class="parameter">action</replaceable> part of the rule is
executed. First, however, values from fields in the current instance
and/or the new instance are substituted for
<literal>current.</literal><replaceable class="parameter">attribute-name</replaceable>
and <literal>new.</literal><replaceable class="parameter">attribute-name</replaceable>.
</para>
<para>
The <replaceable class="parameter">action</replaceable> part of the rule
executes with the same command and transaction identifier as the user
command that caused activation.
</para>
<refsect2 id="R2-SQL-CREATERULE-3">
<refsect2info>
<date>1998-09-11</date>
</refsect2info>
<title>
Notes
</title>
<para>
A caution about SQL rules is in order. If the same class name
or instance variable appears in the
<replaceable class="parameter">event</replaceable>, the
<replaceable class="parameter">condition</replaceable> and the
<replaceable class="parameter">action</replaceable> parts of a rule,
they are all considered different tuple variables. More accurately,
<literal>new</literal> and <literal>current</literal> are the only tuple
variables that are shared between these clauses. For example, the following
two rules have the same semantics:
<programlisting>
ON UPDATE TO emp.salary WHERE emp.name = "Joe"
DO UPDATE emp ( ... ) WHERE ...
</programlisting>
<programlisting>
ON UPDATE TO emp-1.salary WHERE emp-2.name = "Joe"
DO UPDATE emp-3 ( ... ) WHERE ...
</programlisting>
Each rule can have the optional tag INSTEAD.
Without
this tag, <replaceable class="parameter">action</replaceable> will be
performed in addition to the user command when the
<replaceable class="parameter">event</replaceable> in the
<replaceable class="parameter">condition</replaceable> part of the rule
occurs. Alternately, the
<replaceable class="parameter">action</replaceable> part will be done
instead of the user command. In this later case, the
<replaceable class="parameter">action</replaceable> can be the keyword
<literal>NOTHING</literal>.
</para>
<para>
When choosing between the rewrite and instance rule systems for a
particular rule application, remember that in the rewrite system,
<literal>current</literal> refers to a relation and some qualifiers
whereas in the instance system it refers to an instance (tuple).
</para>
<para>
It is very important to note that the rewrite rule system
will neither detect nor process circular rules. For example, though each
of the following two rule definitions are accepted by
<productname>Postgres</productname>, the
retrieve command will cause <productname>Postgres</productname> to crash:
<example>
<title>Example of a circular rewrite rule combination.</title>
<programlisting>
CREATE RULE bad_rule_combination_1 AS
ON SELECT TO emp
DO INSTEAD SELECT TO toyemp;
</programlisting>
<programlisting>
CREATE RULE bad_rule_combination_2 AS
ON SELECT TO toyemp
DO INSTEAD SELECT TO emp;
</programlisting>
<para>
This attempt to retrieve from EMP will cause
<productname>Postgres</productname> to crash.
<programlisting>
SELECT * FROM emp;
</programlisting></para>
</example>
</para>
<para>
You must have rule definition access to a class in order
to define a rule on it. Use <command>GRANT</command>
and <command>REVOKE</command> to change permissions.
</para>
</refsect2>
</refsect1>
<refsect1 id="R1-SQL-CREATERULE-2">
<title>
Usage
</title>
<para>
Make Sam get the same salary adjustment as Joe:
<programlisting>
CREATE RULE example_1 AS
ON UPDATE emp.salary WHERE current.name = "Joe"
DO UPDATE emp (salary = new.salary)
WHERE emp.name = "Sam";
</programlisting>
At the time Joe receives a salary adjustment, the event
will become true and Joe's current instance and proposed
new instance are available to the execution routines.
Hence, his new salary is substituted into the action part
of the rule which is subsequently executed. This propagates
Joe's salary on to Sam.
</para>
<para>
Make Bill get Joe's salary when it is accessed:
<programlisting>
CREATE RULE example_2 AS
ON SELECT TO EMP.salary
WHERE current.name = "Bill"
DO INSTEAD
SELECT (emp.salary) from emp
WHERE emp.name = "Joe";
</programlisting>
</para>
<para>
Deny Joe access to the salary of employees in the shoe
department (<function>current_user</function> returns the name of
the current user):
<programlisting>
CREATE RULE example_3 AS
ON SELECT TO emp.salary
WHERE current.dept = "shoe" AND current_user = "Joe"
DO INSTEAD NOTHING;
</programlisting>
</para>
<para>
Create a view of the employees working in the toy department.
<programlisting>
CREATE toyemp(name = char16, salary = int4);
CREATE RULE example_4 AS
ON SELECT TO toyemp
DO INSTEAD
SELECT (emp.name, emp.salary) FROM emp
WHERE emp.dept = "toy";
</programlisting>
</para>
<para>
All new employees must make 5,000 or less
<programlisting>
CREATE RULE example_5 AS
ON INERT TO emp WHERE new.salary > 5000
DO UPDATE NEWSET salary = 5000;
</programlisting>
</para>
</refsect1>
<refsect1 id="R1-SQL-CREATERULE-3">
<title>
Bugs
</title>
<para>
The object in a <acronym>SQL</acronym> rule cannot be an array reference and
cannot have parameters.
</para>
<para>
Aside from the "oid" field, system attributes cannot be
referenced anywhere in a rule. Among other things, this
means that functions of instances (e.g., "<literal>foo(emp)</literal>" where
"<literal>emp</literal>" is a class) cannot be called anywhere in a rule.
</para>
<para>
The rule system stores the rule text and query plans as
text attributes. This implies that creation of rules may
fail if the rule plus its various internal representations
exceed some value that is on the order of one page (8KB).
</para>
</refsect1>
<refsect1 id="R1-SQL-CREATERULE-4">
<title>
Compatibility
</title>
<para>
<command>CREATE RULE</command> statement is a <productname>Postgres</productname>
language extension.
</para>
<refsect2 id="R2-SQL-CREATERULE-4">
<refsect2info>
<date>1998-09-11</date>
</refsect2info>
<title>
SQL92
</title>
<para>
There is no <command>CREATE RULE</command> statement in <acronym>SQL92</acronym>.
</para>
</refsect2>
</refsect1>
</refentry>
<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->
|