CREATE RULE name AS ON event TO object [ WHERE condition ] DO [ INSTEAD ] [ action | NOTHING ]
The name of a rule to create.
Event is one of select, update, delete or insert.
Object is either table or table.column.
Any SQL WHERE clause, new or old can appear instead of an instance variable whenever an instance variable is permissible in SQL.
Any SQL statement, new or old can appear instead of an instance variable whenever an instance variable is permissible in SQL.
Message returned if the rule is successfully created.
The Postgres rule system allows one to define an alternate action to be performed on inserts, updates, or deletions from database tables or classes. Currently, rules are used to implement table views.
The semantics of a rule is that at the time an individual instance is accessed, inserted, updated, or deleted, there is a old instance (for selects, updates and deletes) and a new instance (for inserts and updates). If the event specified in the ON clause and the condition specified in the WHERE clause are true for the old instance, the action part of the rule is executed. First, however, 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 executes with the same command and transaction identifier as the user command that caused activation.
A caution about SQL rules is in order. If the same class name or instance variable appears in the event, condition and action parts of a rule, they are all considered different tuple variables. More accurately, new and old are the only tuple variables that are shared between these clauses. For example, the following two rules have the same semantics:
ON UPDATE TO emp.salary WHERE emp.name = "Joe" DO UPDATE emp SET ... WHERE ...
ON UPDATE TO emp-1.salary WHERE emp-2.name = "Joe" DO UPDATE emp-3 SET ... WHERE ...Each rule can have the optional tag INSTEAD. Without this tag, action will be performed in addition to the user command when the event in the condition part of the rule occurs. Alternately, the action part will be done instead of the user command. In this later case, the action can be the keyword NOTHING.
It is very important to note to avoid circular rules. For example, though each of the following two rule definitions are accepted by Postgres, the select command will cause Postgres to report an error because the query cycled too many times:
Example 19-1. Example of a circular rewrite rule combination.
CREATE RULE bad_rule_combination_1 AS ON SELECT TO emp DO INSTEAD SELECT TO toyemp;
CREATE RULE bad_rule_combination_2 AS ON SELECT TO toyemp DO INSTEAD SELECT TO emp;
This attempt to select from EMP will cause Postgres to issue an error because the queries cycled too many times.
SELECT * FROM emp;
You must have rule definition access to a class in order to define a rule on it. Use GRANT and REVOKE to change permissions.
The object in a SQL rule cannot be an array reference and cannot have parameters.
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., foo(emp) where emp is a class) cannot be called anywhere in a rule.
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).
Make Sam get the same salary adjustment as Joe:
CREATE RULE example_1 AS ON UPDATE emp.salary WHERE old.name = "Joe" DO UPDATE emp SET salary = new.salary WHERE emp.name = "Sam";At the time Joe receives a salary adjustment, the event will become true and Joe's old 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.
Make Bill get Joe's salary when it is accessed:
CREATE RULE example_2 AS ON SELECT TO EMP.salary WHERE old.name = "Bill" DO INSTEAD SELECT emp.salary FROM emp WHERE emp.name = "Joe";
Deny Joe access to the salary of employees in the shoe department (current_user returns the name of the current user):
CREATE RULE example_3 AS ON SELECT TO emp.salary WHERE old.dept = "shoe" AND current_user = "Joe" DO INSTEAD NOTHING;
Create a view of the employees working in the toy department.
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";
All new employees must make 5,000 or less
CREATE RULE example_5 AS ON INERT TO emp WHERE new.salary > 5000 DO UPDATE NEWSET SET salary = 5000;
CREATE RULE statement is a Postgres language extension. There is no CREATE RULE statement in SQL92.