CREATE RULE
SQL - Language Statements
CREATE RULE
define a new rewrite rule
2001-01-05
CREATE RULE name AS ON event
TO object [ WHERE condition ]
DO [ INSTEAD ] action
where action can be:
NOTHING
|
query
|
( query ; query ... )
|
[ query ; query ... ]
2001-01-05
Inputs
name
The name of a rule to create.
event
Event is one of SELECT,
UPDATE, DELETE
or INSERT.
object
Object is either table
or table.column. (Currently, only the
table form is
actually implemented.)
condition
Any SQL boolean-condition expression. The condition expression may not
refer to any tables except new and
old.
query
The query or queries making up the
action
can be any SQL SELECT, INSERT,
UPDATE, DELETE, or
NOTIFY statement.
Within the condition
and action, the special
table names new and old may be
used to refer to values in the referenced table (the
object).
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.
1998-09-11
Outputs
CREATE
Message returned if the rule is successfully created.
1998-09-11
Description
The PostgreSQL
rule system allows one to define an
alternate action to be performed on inserts, updates, or deletions
from database tables. Rules are used to
implement table views as well.
The semantics of a rule is that at the time an individual instance (row)
is
accessed, inserted, updated, or deleted, there is an old instance (for
selects, updates and deletes) and a new instance (for inserts and
updates). All the rules for the given event type and the given target
object (table) are examined, in an unspecified order. If the
condition specified in the
WHERE clause (if any) is true, the
action part of the rule is
executed. The action is
done instead of the original query if INSTEAD is specified; otherwise
it is done after the original query in the case of ON INSERT, or before
the original query in the case of ON UPDATE or ON DELETE.
Within both the condition
and action, values from
fields in the old instance and/or the new instance are substituted for
old.attribute-name
and new.attribute-name.
The action part of the rule
can consist of one or more queries. To write multiple queries, surround
them with either parentheses or square brackets. Such queries will be
performed in the specified order (whereas there are no guarantees about
the execution order of multiple rules for an object). The
action can also be NOTHING
indicating no action. Thus, a DO INSTEAD NOTHING rule suppresses the
original query from executing (when its condition is true); a DO NOTHING
rule is useless.
The action part of the rule
executes with the same command and transaction identifier as the user
command that caused activation.
2001-11-06
Rules and Views
Presently, ON SELECT rules must be unconditional INSTEAD rules and must
have actions that consist of a single SELECT query. Thus, an ON SELECT
rule effectively turns the object table into a view, whose visible
contents are the rows returned by the rule's SELECT query rather than
whatever had been stored in the table (if anything). It is considered
better style to write a CREATE VIEW command than to create a real table
and define an ON SELECT rule for it.
creates a dummy table (with no underlying
storage) and associates an ON SELECT rule with it. The system will not
allow updates to the view, since it knows there is no real table there.
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's sufficient
for your purposes) to replace update actions on the view with
appropriate updates on other tables.
There is a catch if you try to use conditional
rules for view updates: there must> 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 in some cases.
If you want to
handle all the useful cases in conditional rules, you can; just 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 fire,
they add to the default INSTEAD NOTHING action.
2001-01-05
Notes
You must have rule definition access to a table in order
to define a rule on it. Use GRANT
and REVOKE to change permissions.
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
select command will cause PostgreSQL to
report an error because the query cycled too many times:
CREATE RULE "_RETemp" AS
ON SELECT TO emp
DO INSTEAD
SELECT * FROM toyemp;
CREATE RULE "_RETtoyemp" AS
ON SELECT TO toyemp
DO INSTEAD
SELECT * FROM emp;
This attempt to select from EMP will cause
PostgreSQL to issue an error
because the queries cycled too many times:
SELECT * FROM emp;
Presently, if a rule contains a NOTIFY query, the NOTIFY will be executed
unconditionally --- that is, the NOTIFY will be issued even if there are
not any rows that the rule should apply to. For example, in
CREATE RULE notify_me AS ON UPDATE TO mytable DO NOTIFY mytable;
UPDATE mytable SET name = 'foo' WHERE id = 42;
one NOTIFY event will be sent during the UPDATE, whether or not there
are any rows with id = 42. This is an implementation restriction that
may be fixed in future releases.
Compatibility
1998-09-11
SQL92
CREATE RULE statement is a PostgreSQL
language extension.
There is no CREATE RULE statement in SQL92.