From dcb00495236d426d036324ba2c2f2222e9c44f11 Mon Sep 17 00:00:00 2001 From: Peter Eisentraut Date: Fri, 11 Apr 2003 13:22:35 +0000 Subject: [PATCH] Revision --- doc/src/sgml/rules.sgml | 1595 +++++++++++++++++++-------------------- 1 file changed, 767 insertions(+), 828 deletions(-) diff --git a/doc/src/sgml/rules.sgml b/doc/src/sgml/rules.sgml index 25c78cce88..66d20cb11b 100644 --- a/doc/src/sgml/rules.sgml +++ b/doc/src/sgml/rules.sgml @@ -1,4 +1,4 @@ - + The Rule System @@ -7,49 +7,33 @@ rules - - Author - - Written by Jan Wieck. Updates for 7.1 by Tom Lane. - - - - - Introduction - + This chapter discusses the rule system in PostgreSQL. Production rule systems are conceptually simple, but there are many subtle points involved in actually using - them. Some of these points and - the theoretical foundations of the PostgreSQL - rule system can be found in -. + them. - Some other database systems define active database rules. These - are usually stored procedures and triggers and are implemented - in PostgreSQL as functions and triggers. + Some other database systems define active database rules, which + are usually stored procedures and triggers. In PostgreSQL, these + can be implemented using functions and triggers as well. - The query rewrite rule system (the rule system from now on) - is totally different from stored procedures and triggers. - It modifies queries to - take rules into consideration, and then passes the modified - query to the query planner for planning and execution. It - is very powerful, and can be used for many things such - as query language procedures, views, and versions. The - power of this rule system is discussed in - - as well as -. + The rule system (more precisely speaking, the query rewrite rule + system) is totally different from stored procedures and triggers. + It modifies queries to take rules into consideration, and then + passes the modified query to the query planner for planning and + execution. It is very powerful, and can be used for many things + such as query language procedures, views, and versions. The + theoretical foundations and the power of this rule system are + also discussed in and . - - -What is a Query Tree? +The Query Tree To understand how the rule system works it is necessary to know @@ -57,10 +41,10 @@ - The rule system is located between the query parser and the planner. - It takes the output of the parser, one query tree, and the rewrite - rules from the pg_rewrite catalog, which are - query trees too with some extra information, and creates zero or many + The rule system is located between the parser and the planner. + It takes the output of the parser, one query tree, and the user-defined + rewrite rules, which are also + query trees with some extra information, and creates zero or more query trees as result. So its input and output are always things the parser itself could have produced and thus, anything it sees is basically representable as an SQL statement. @@ -68,34 +52,27 @@ Now what is a query tree? It is an internal representation of an - SQL statement where the single parts that built - it are stored separately. These query trees are visible when starting - the PostgreSQL backend with debug level 4 - and typing queries into the interactive backend interface. The rule - actions in the pg_rewrite system catalog are - also stored as query trees. They are not formatted like the debug - output, but they contain exactly the same information. + SQL statement where the single parts that it is + built from are stored separately. These query trees can be shown + in the server log if you set the configuration parameters + debug_print_parse, + debug_print_rewritten, or + debug_print_plan. The rule actions are also + stored as query trees, in the system catalog + pg_rewrite. They are not formatted like + the log output, but they contain exactly the same information. - Reading a query tree requires some experience and it was a hard - time when I started to work on the rule system. I can remember - that I was standing at the coffee machine and I saw the cup - in a target list, water and coffee powder in a range table and all - the buttons in a qualification expression. Since + Reading a raw query tree requires some experience. But since SQL representations of query trees are - sufficient to understand the rule system, this document will - not teach how to read them. It might help to learn - it and the naming conventions are required in the later following - descriptions. + sufficient to understand the rule system, this chapter will not + teach how to read them. - -The Parts of a Query tree - When reading the SQL representations of the - query trees in this document it is necessary to be able to identify + query trees in this chapter it is necessary to be able to identify the parts the statement is broken into when it is in the query tree structure. The parts of a query tree are @@ -109,7 +86,7 @@ This is a simple value telling which command (SELECT, INSERT, UPDATE, DELETE) produced - the parse tree. + the query tree. @@ -123,17 +100,17 @@ The range table is a list of relations that are used in the query. In a SELECT statement these are the relations given after - the FROM keyword. + the FROM key word. Every range table entry identifies a table or view and tells by which name it is called in the other parts of the query. - In the query tree the range table entries are referenced by - index rather than by name, so here it doesn't matter if there + In the query tree, the range table entries are referenced by + number rather than by name, so here it doesn't matter if there are duplicate names as it would in an SQL statement. This can happen after the range tables of rules - have been merged in. The examples in this document will not have + have been merged in. The examples in this chapter will not have this situation. @@ -152,14 +129,14 @@ SELECT queries normally don't have a result relation. The special case of a SELECT INTO is - mostly identical to a CREATE TABLE, - INSERT ... SELECT sequence and is not discussed + mostly identical to a CREATE TABLE followed by a + INSERT ... SELECT and is not discussed separately here. - On INSERT, UPDATE and - DELETE queries the result relation is the table + For INSERT, UPDATE, and + DELETE commands, the result relation is the table (or view!) where the changes take effect. @@ -172,50 +149,51 @@ The target list is a list of expressions that define the - result of the query. In the case of a SELECT, - the expressions are what builds the final output of the - query. They are the expressions between the - SELECT and the FROM keywords. - (* is just an abbreviation for all the - attribute names of a relation. It is expanded by the parser into - the individual attributes, so the rule system never sees it.) + result of the query. In the case of a + SELECT, these expressions are the ones that + build the final output of the query. They correspond to the + expressions between the key words SELECT + and FROM. (* is just an + abbreviation for all the column names of a relation. It is + expanded by the parser into the individual columns, so the + rule system never sees it.) - DELETE queries don't need a target list - because they don't produce any result. In fact the planner will - add a special CTID entry to the empty target list. But - this is after the rule system and will be discussed later. For the - rule system the target list is empty. + DELETE commands don't need a target list + because they don't produce any result. In fact, the planner will + add a special CTID entry to the empty target list, but + this is after the rule system and will be discussed later; for the + rule system, the target list is empty. - In INSERT queries the target list describes - the new rows that should go into the result relation. It is the - expressions in the VALUES clause or the ones from the + For INSERT commands, the target list describes + the new rows that should go into the result relation. It consists of the + expressions in the VALUES clause or the ones from the SELECT clause in INSERT ... SELECT. The first step of the rewrite process adds target list entries for any columns that were not assigned to by - the original query and have defaults. Any remaining columns (with + the original command but have defaults. Any remaining columns (with neither a given value nor a default) will be filled in by the - planner with a constant NULL expression. + planner with a constant null expression. - In UPDATE queries, the target list + For UPDATE commands, the target list describes the new rows that should replace the old ones. In the - rule system, it contains just the expressions from the SET - attribute = expression part of the query. The planner will handle + rule system, it contains just the expressions from the SET + column = expression part of the command. The planner will handle missing columns by inserting expressions that copy the values from the old row into the new one. And it will add the special - CTID entry just as for DELETE too. + CTID entry just as for DELETE, too. Every entry in the target list contains an expression that can - be a constant value, a variable pointing to an attribute of one + be a constant value, a variable pointing to a column of one of the relations in the range table, a parameter, or an expression - tree made of function calls, constants, variables, operators etc. + tree made of function calls, constants, variables, operators, etc. @@ -228,10 +206,10 @@ The query's qualification is an expression much like one of those contained in the target list entries. The result value of - this expression is a Boolean that tells if the operation + this expression is a Boolean that tells whether the operation (INSERT, UPDATE, - DELETE or SELECT) for the - final result row should be executed or not. It is the WHERE clause + DELETE, or SELECT) for the + final result row should be executed or not. It corresponds to the WHERE clause of an SQL statement. @@ -243,18 +221,18 @@ - The query's join tree shows the structure of the FROM clause. - For a simple query like SELECT FROM a, b, c the join tree is just - a list of the FROM items, because we are allowed to join them in - any order. But when JOIN expressions --- particularly outer joins - --- are used, we have to join in the order shown by the joins. - The join tree shows the structure of the JOIN expressions. The - restrictions associated with particular JOIN clauses (from ON or - USING expressions) are stored as qualification expressions attached - to those join tree nodes. It turns out to be convenient to store - the top-level WHERE expression as a qualification attached to the - top-level join tree item, too. So really the join tree represents - both the FROM and WHERE clauses of a SELECT. + The query's join tree shows the structure of the FROM clause. + For a simple query like SELECT ... FROM a, b, c, the join tree is just + a list of the FROM items, because we are allowed to join them in + any order. But when JOIN expressions, particularly outer joins, + are used, we have to join in the order shown by the joins. + In that case, the join tree shows the structure of the JOIN expressions. The + restrictions associated with particular JOIN clauses (from ON or + USING expressions) are stored as qualification expressions attached + to those join-tree nodes. It turns out to be convenient to store + the top-level WHERE expression as a qualification attached to the + top-level join-tree item, too. So really the join tree represents + both the FROM and WHERE clauses of a SELECT. @@ -265,9 +243,9 @@ - The other parts of the query tree like the ORDER BY + The other parts of the query tree like the ORDER BY clause aren't of interest here. The rule system - substitutes entries there while applying rules, but that + substitutes some entries there while applying rules, but that doesn't have much to do with the fundamentals of the rule system. @@ -276,19 +254,15 @@ - Views and the Rule System rulesand views - -Implementation of Views in <ProductName>PostgreSQL</ProductName> - Views in PostgreSQL are implemented - using the rule system. In fact there is essentially no difference + using the rule system. In fact, there is essentially no difference between @@ -298,7 +272,7 @@ CREATE VIEW myview AS SELECT * FROM mytab; compared against the two commands -CREATE TABLE myview (same attribute list as for mytab); +CREATE TABLE myview (same column list as mytab); CREATE RULE "_RETURN" AS ON SELECT TO myview DO INSTEAD SELECT * FROM mytab; @@ -307,60 +281,51 @@ CREATE RULE "_RETURN" AS ON SELECT TO myview DO INSTEAD command does internally. This has some side effects. One of them is that the information about a view in the PostgreSQL system catalogs is exactly - the same as it is for a table. So for the query parser, there is + the same as it is for a table. So for the parser, there is absolutely no difference between a table and a view. They are the - same thing - relations. That is the important one for now. + same thing: relations. - How <command>SELECT</command> Rules Work - Rules ON SELECT are applied to all queries as the last step, even + Rules ON SELECT are applied to all queries as the last step, even if the command given is an INSERT, UPDATE or DELETE. And they - have different semantics from the others in that they modify the - parse tree in place instead of creating a new one. So + have different semantics from rules on the other command types in that they modify the + query tree in place instead of creating a new one. So SELECT rules are described first. - Currently, there can be only one action in an ON SELECT rule, and it must - be an unconditional SELECT action that is INSTEAD. This restriction was - required to make rules safe enough to open them for ordinary users and - it restricts rules ON SELECT to real view rules. + Currently, there can be only one action in an ON SELECT rule, and it must + be an unconditional SELECT action that is INSTEAD. This restriction was + required to make rules safe enough to open them for ordinary users, and + it restricts ON SELECT rules to real view rules. - The examples for this document are two join views that do some + The examples for this chapter are two join views that do some calculations and some more views using them in turn. One of the two first views is customized later by adding rules for - INSERT, UPDATE and + INSERT, UPDATE, and DELETE operations so that the final result will be a view that behaves like a real table with some magic - functionality. It is not such a simple example to start from and + functionality. This is not such a simple example to start from and this makes things harder to get into. But it's better to have one example that covers all the points discussed step by step rather than having many different ones that might mix up in mind. - The database needed to play with the examples is named al_bundy. - You'll see soon why this is the database name. And it needs the - procedural language PL/pgSQL installed, because - we need a little min() function returning the lower of 2 - integer values. We create that as +For the example, we need a little min function that +returns the lower of 2 integer values. We create that as CREATE FUNCTION min(integer, integer) RETURNS integer AS ' - BEGIN - IF $1 < $2 THEN - RETURN $1; - END IF; - RETURN $2; - END; -' LANGUAGE plpgsql; + SELECT CASE WHEN $1 < $2 THEN $1 ELSE $2 END +' LANGUAGE SQL STRICT; @@ -370,32 +335,29 @@ CREATE FUNCTION min(integer, integer) RETURNS integer AS ' CREATE TABLE shoe_data ( - shoename char(10), -- primary key - sh_avail integer, -- available # of pairs - slcolor char(10), -- preferred shoelace color - slminlen float, -- miminum shoelace length - slmaxlen float, -- maximum shoelace length - slunit char(8) -- length unit + shoename text, -- primary key + sh_avail integer, -- available number of pairs + slcolor text, -- preferred shoelace color + slminlen real, -- minimum shoelace length + slmaxlen real, -- maximum shoelace length + slunit text -- length unit ); CREATE TABLE shoelace_data ( - sl_name char(10), -- primary key - sl_avail integer, -- available # of pairs - sl_color char(10), -- shoelace color - sl_len float, -- shoelace length - sl_unit char(8) -- length unit + sl_name text, -- primary key + sl_avail integer, -- available number of pairs + sl_color text, -- shoelace color + sl_len real, -- shoelace length + sl_unit text -- length unit ); CREATE TABLE unit ( - un_name char(8), -- the primary key - un_fact float -- factor to transform to cm + un_name text, -- primary key + un_fact real -- factor to transform to cm ); - I think most of us wear shoes and can realize that this is - really useful data. Well there are shoes out in the world - that don't require shoelaces, but this doesn't make Al's - life easier and so we ignore it. + As you can see, they represent shoe-store data. @@ -438,84 +400,72 @@ CREATE VIEW shoe_ready AS The CREATE VIEW command for the shoelace view (which is the simplest one we - have) will create a relation shoelace and an entry in + have) will create a relation shoelace and an entry in pg_rewrite that tells that there is a - rewrite rule that must be applied whenever the relation shoelace + rewrite rule that must be applied whenever the relation shoelace is referenced in a query's range table. The rule has no rule - qualification (discussed later, with the non SELECT rules, since - SELECT rules currently cannot have them) and it is INSTEAD. Note - that rule qualifications are not the same as query qualifications! - The rule's action has a query qualification. - - - - The rule's action is one query tree that is a copy of the + qualification (discussed later, with the non-SELECT rules, since + SELECT rules currently cannot have them) and it is INSTEAD. Note + that rule qualifications are not the same as query qualifications. + The action of our rule has a query qualification. + The action of the rule is one query tree that is a copy of the SELECT statement in the view creation command. + - Note The two extra range - table entries for NEW and OLD (named *NEW* and *CURRENT* for + table entries for NEW and OLD (named *NEW* and *OLD* for historical reasons in the printed query tree) you can see in the pg_rewrite entry aren't of interest - for SELECT rules. + for SELECT rules. + Now we populate unit, shoe_data - and shoelace_data and Al types the first - SELECT in his life: + and shoelace_data and run a simple query on a view: -al_bundy=> INSERT INTO unit VALUES ('cm', 1.0); -al_bundy=> INSERT INTO unit VALUES ('m', 100.0); -al_bundy=> INSERT INTO unit VALUES ('inch', 2.54); -al_bundy=> -al_bundy=> INSERT INTO shoe_data VALUES -al_bundy-> ('sh1', 2, 'black', 70.0, 90.0, 'cm'); -al_bundy=> INSERT INTO shoe_data VALUES -al_bundy-> ('sh2', 0, 'black', 30.0, 40.0, 'inch'); -al_bundy=> INSERT INTO shoe_data VALUES -al_bundy-> ('sh3', 4, 'brown', 50.0, 65.0, 'cm'); -al_bundy=> INSERT INTO shoe_data VALUES -al_bundy-> ('sh4', 3, 'brown', 40.0, 50.0, 'inch'); -al_bundy=> -al_bundy=> INSERT INTO shoelace_data VALUES -al_bundy-> ('sl1', 5, 'black', 80.0, 'cm'); -al_bundy=> INSERT INTO shoelace_data VALUES -al_bundy-> ('sl2', 6, 'black', 100.0, 'cm'); -al_bundy=> INSERT INTO shoelace_data VALUES -al_bundy-> ('sl3', 0, 'black', 35.0 , 'inch'); -al_bundy=> INSERT INTO shoelace_data VALUES -al_bundy-> ('sl4', 8, 'black', 40.0 , 'inch'); -al_bundy=> INSERT INTO shoelace_data VALUES -al_bundy-> ('sl5', 4, 'brown', 1.0 , 'm'); -al_bundy=> INSERT INTO shoelace_data VALUES -al_bundy-> ('sl6', 0, 'brown', 0.9 , 'm'); -al_bundy=> INSERT INTO shoelace_data VALUES -al_bundy-> ('sl7', 7, 'brown', 60 , 'cm'); -al_bundy=> INSERT INTO shoelace_data VALUES -al_bundy-> ('sl8', 1, 'brown', 40 , 'inch'); -al_bundy=> -al_bundy=> SELECT * FROM shoelace; -sl_name |sl_avail|sl_color |sl_len|sl_unit |sl_len_cm -----------+--------+----------+------+--------+--------- -sl1 | 5|black | 80|cm | 80 -sl2 | 6|black | 100|cm | 100 -sl7 | 7|brown | 60|cm | 60 -sl3 | 0|black | 35|inch | 88.9 -sl4 | 8|black | 40|inch | 101.6 -sl8 | 1|brown | 40|inch | 101.6 -sl5 | 4|brown | 1|m | 100 -sl6 | 0|brown | 0.9|m | 90 +INSERT INTO unit VALUES ('cm', 1.0); +INSERT INTO unit VALUES ('m', 100.0); +INSERT INTO unit VALUES ('inch', 2.54); + +INSERT INTO shoe_data VALUES ('sh1', 2, 'black', 70.0, 90.0, 'cm'); +INSERT INTO shoe_data VALUES ('sh2', 0, 'black', 30.0, 40.0, 'inch'); +INSERT INTO shoe_data VALUES ('sh3', 4, 'brown', 50.0, 65.0, 'cm'); +INSERT INTO shoe_data VALUES ('sh4', 3, 'brown', 40.0, 50.0, 'inch'); + +INSERT INTO shoelace_data VALUES ('sl1', 5, 'black', 80.0, 'cm'); +INSERT INTO shoelace_data VALUES ('sl2', 6, 'black', 100.0, 'cm'); +INSERT INTO shoelace_data VALUES ('sl3', 0, 'black', 35.0 , 'inch'); +INSERT INTO shoelace_data VALUES ('sl4', 8, 'black', 40.0 , 'inch'); +INSERT INTO shoelace_data VALUES ('sl5', 4, 'brown', 1.0 , 'm'); +INSERT INTO shoelace_data VALUES ('sl6', 0, 'brown', 0.9 , 'm'); +INSERT INTO shoelace_data VALUES ('sl7', 7, 'brown', 60 , 'cm'); +INSERT INTO shoelace_data VALUES ('sl8', 1, 'brown', 40 , 'inch'); + +SELECT * FROM shoelace; + + sl_name | sl_avail | sl_color | sl_len | sl_unit | sl_len_cm +-----------+----------+----------+--------+---------+----------- + sl1 | 5 | black | 80 | cm | 80 + sl2 | 6 | black | 100 | cm | 100 + sl7 | 7 | brown | 60 | cm | 60 + sl3 | 0 | black | 35 | inch | 88.9 + sl4 | 8 | black | 40 | inch | 101.6 + sl8 | 1 | brown | 40 | inch | 101.6 + sl5 | 4 | brown | 1 | m | 100 + sl6 | 0 | brown | 0.9 | m | 90 (8 rows) + - It's the simplest SELECT Al can do on our + + This is the simplest SELECT you can do on our views, so we take this opportunity to explain the basics of view rules. The SELECT * FROM shoelace was - interpreted by the parser and produced the parse tree + interpreted by the parser and produced the query tree SELECT shoelace.sl_name, shoelace.sl_avail, @@ -525,30 +475,26 @@ SELECT shoelace.sl_name, shoelace.sl_avail, and this is given to the rule system. The rule system walks through the - range table and checks if there are rules in pg_rewrite + range table and checks if there are rules for any relation. When processing the range table entry for shoelace (the only one up to now) it finds the - _RETURN rule with the parse tree + _RETURN rule with the query tree -SELECT s.sl_name, s.sl_avail, +SELECT s.sl_name, s.sl_avail, s.sl_color, s.sl_len, s.sl_unit, - float8mul(s.sl_len, u.un_fact) AS sl_len_cm + s.sl_len * u.un_fact AS sl_len_cm FROM shoelace *OLD*, shoelace *NEW*, shoelace_data s, unit u - WHERE bpchareq(s.sl_unit, u.un_name); + WHERE s.sl_unit = u.un_name; - - Note that the parser changed the calculation and qualification into - calls to the appropriate functions. But - in fact this changes nothing. - To expand the view, the rewriter simply creates a subselect range-table - entry containing the rule's action parse tree, and substitutes this + To expand the view, the rewriter simply creates a subquery range-table + entry containing the rule's action query tree, and substitutes this range table entry for the original one that referenced the view. The - resulting rewritten parse tree is almost the same as if Al had typed + resulting rewritten query tree is almost the same as if you had typed SELECT shoelace.sl_name, shoelace.sl_avail, @@ -564,13 +510,13 @@ SELECT shoelace.sl_name, shoelace.sl_avail, WHERE s.sl_unit = u.un_name) shoelace; - There is one difference however: the sub-query's range table has two - extra entries shoelace *OLD*, shoelace *NEW*. These entries don't + There is one difference however: the subquery's range table has two + extra entries shoelace *OLD* and shoelace *NEW*. These entries don't participate directly in the query, since they aren't referenced by - the sub-query's join tree or target list. The rewriter uses them - to store the access permission check info that was originally present + the subquery's join tree or target list. The rewriter uses them + to store the access privilege check information that was originally present in the range-table entry that referenced the view. In this way, the - executor will still check that the user has proper permissions to access + executor will still check that the user has proper privileges to access the view, even though there's no direct use of the view in the rewritten query. @@ -579,55 +525,43 @@ SELECT shoelace.sl_name, shoelace.sl_avail, That was the first rule applied. The rule system will continue checking the remaining range-table entries in the top query (in this example there are no more), and it will recursively check the range-table entries in - the added sub-query to see if any of them reference views. (But it - won't expand *OLD* or *NEW* --- otherwise we'd have infinite recursion!) - In this example, there are no rewrite rules for shoelace_data or unit, + the added subquery to see if any of them reference views. (But it + won't expand *OLD* or *NEW* --- otherwise we'd have infinite recursion!) + In this example, there are no rewrite rules for shoelace_data or unit, so rewriting is complete and the above is the final result given to the planner. - Now we face Al with the problem that the Blues Brothers appear - in his shop and - want to buy some new shoes, and as the Blues Brothers are, - they want to wear the same shoes. And they want to wear them - immediately, so they need shoelaces too. - - - - Al needs to know for which shoes currently in the store - he has the matching shoelaces (color and size) and where the + No we want to write a query that finds out for which shoes currently in the store + we have the matching shoelaces (color and length) and where the total number of exactly matching pairs is greater or equal to two. - We teach him what to do and he asks his database: -al_bundy=> SELECT * FROM shoe_ready WHERE total_avail >= 2; -shoename |sh_avail|sl_name |sl_avail|total_avail -----------+--------+----------+--------+----------- -sh1 | 2|sl1 | 5| 2 -sh3 | 4|sl7 | 7| 4 +SELECT * FROM shoe_ready WHERE total_avail >= 2; + + shoename | sh_avail | sl_name | sl_avail | total_avail +----------+----------+---------+----------+------------- + sh1 | 2 | sl1 | 5 | 2 + sh3 | 4 | sl7 | 7 | 4 (2 rows) - - Al is a shoe guru and so he knows that only shoes of type sh1 - would fit (shoelace sl7 is brown and shoes that need brown shoelaces - aren't shoes the Blues Brothers would ever wear). - The output of the parser this time is the parse tree + The output of the parser this time is the query tree SELECT shoe_ready.shoename, shoe_ready.sh_avail, shoe_ready.sl_name, shoe_ready.sl_avail, shoe_ready.total_avail FROM shoe_ready shoe_ready - WHERE int4ge(shoe_ready.total_avail, 2); + WHERE shoe_ready.total_avail >= 2; The first rule applied will be the one for the shoe_ready view and it results in the - parse tree + query tree SELECT shoe_ready.shoename, shoe_ready.sh_avail, @@ -642,12 +576,12 @@ SELECT shoe_ready.shoename, shoe_ready.sh_avail, WHERE rsl.sl_color = rsh.slcolor AND rsl.sl_len_cm >= rsh.slminlen_cm AND rsl.sl_len_cm <= rsh.slmaxlen_cm) shoe_ready - WHERE int4ge(shoe_ready.total_avail, 2); + WHERE shoe_ready.total_avail >= 2; Similarly, the rules for shoe and shoelace are substituted into the range table of - the sub-query, leading to a three-level final query tree: + the subquery, leading to a three-level final query tree: SELECT shoe_ready.shoename, shoe_ready.sh_avail, @@ -679,25 +613,29 @@ SELECT shoe_ready.shoename, shoe_ready.sh_avail, WHERE rsl.sl_color = rsh.slcolor AND rsl.sl_len_cm >= rsh.slminlen_cm AND rsl.sl_len_cm <= rsh.slmaxlen_cm) shoe_ready - WHERE int4ge(shoe_ready.total_avail, 2); + WHERE shoe_ready.total_avail > 2; + - It turns out that the planner will collapse this tree into a two-level - query tree: the bottommost selects will be pulled up into the middle - select since there's no need to process them separately. But the - middle select will remain separate from the top, because it contains - aggregate functions. If we pulled those up it would change the behavior - of the topmost select, which we don't want. However, collapsing the - query tree is an optimization that the rewrite system doesn't - have to concern itself with. + + It turns out that the planner will collapse this tree into a + two-level query tree: the bottommost SELECT + commands will be pulled up into the middle + SELECT since there's no need to process them + separately. But the middle SELECT will remain + separate from the top, because it contains aggregate functions. + If we pulled those up it would change the behavior of the topmost + SELECT, which we don't want. However, + collapsing the query tree is an optimization that the rewrite + system doesn't have to concern itself with. + - - Note + There is currently no recursion stopping mechanism for view rules in the rule system (only for the other kinds of rules). This doesn't hurt much, because the only way to push this into an - endless loop (blowing up the backend until it reaches the memory + endless loop (bloating up the server process until it reaches the memory limit) is to create tables and then setup the view rules by hand with CREATE RULE in such a way, that one selects from the other that selects from the one. This could @@ -705,28 +643,27 @@ SELECT shoe_ready.shoename, shoe_ready.sh_avail, the first CREATE VIEW, the second relation does not exist and thus the first view cannot select from the second. - - - + -View Rules in Non-SELECT Statements +View Rules in Non-<command>SELECT</command> Statements - Two details of the parse tree aren't touched in the description of + Two details of the query tree aren't touched in the description of view rules above. These are the command type and the result relation. In fact, view rules don't need this information. - There are only a few differences between a parse tree for a - SELECT and one for any other command. Obviously - they have another command type and this time the result relation - points to the range table entry where the result should - go. Everything else is absolutely the same. So having two tables - t1 and t2 with attributes a and b, the parse trees for the two - statements + There are only a few differences between a query tree for a + SELECT and one for any other + command. Obviously, they have a different command type and for a + command other than a SELECT, the result + relation points to the range-table entry where the result should + go. Everything else is absolutely the same. So having two tables + t1 and t2 with columns a and + b, the query trees for the two statements SELECT t2.b FROM t1, t2 WHERE t1.a = t2.a; @@ -734,40 +671,42 @@ SELECT t2.b FROM t1, t2 WHERE t1.a = t2.a; UPDATE t1 SET b = t2.b WHERE t1.a = t2.a; - are nearly identical. + are nearly identical. In particular: - The range tables contain entries for the tables t1 and t2. + The range tables contain entries for the tables t1 and t2. - The target lists contain one variable that points to attribute - b of the range table entry for table t2. + The target lists contain one variable that points to column + b of the range table entry for table t2. - The qualification expressions compare the attributes a of both - ranges for equality. + The qualification expressions compare the columns a of both + range-table entries for equality. - The join trees show a simple join between t1 and t2. + The join trees show a simple join between t1 and t2. + - The consequence is, that both parse trees result in similar - execution plans. They are both joins over the two tables. For the - UPDATE the missing columns from t1 are added to - the target list by the planner and the final parse tree will read + + The consequence is, that both query trees result in similar + execution plans: They are both joins over the two tables. For the + UPDATE the missing columns from t1 are added to + the target list by the planner and the final query tree will read as @@ -782,14 +721,14 @@ SELECT t1.a, t2.b FROM t1, t2 WHERE t1.a = t2.a; will do. But there is a little problem in - UPDATE. The executor does not care what the + UPDATE: The executor does not care what the results from the join it is doing are meant for. It just produces a result set of rows. The difference that one is a SELECT command and the other is an UPDATE is handled in the caller of the - executor. The caller still knows (looking at the parse tree) that - this is an UPDATE, and he knows that this - result should go into table t1. But which of the rows that are + executor. The caller still knows (looking at the query tree) that + this is an UPDATE, and it knows that this + result should go into table t1. But which of the rows that are there has to be replaced by the new row? @@ -797,10 +736,10 @@ SELECT t1.a, t2.b FROM t1, t2 WHERE t1.a = t2.a; To resolve this problem, another entry is added to the target list in UPDATE (and also in DELETE) statements: the current tuple ID - (CTID). This is a system attribute containing the + (CTID). This is a system column containing the file block number and position in the block for the row. Knowing the table, the CTID can be used to retrieve the - original t1 row to be updated. After adding the CTID + original row of t1 to be updated. After adding the CTID to the target list, the query actually looks like @@ -808,13 +747,13 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a; Now another detail of PostgreSQL enters - the stage. At this moment, table rows aren't overwritten and this - is why ABORT TRANSACTION is fast. In an UPDATE, - the new result row is inserted into the table (after stripping - CTID) and in the tuple header of the row that - CTID pointed to the cmax and + the stage. Old table rows aren't overwritten, and this + is why ROLLBACK is fast. In an UPDATE, + the new result row is inserted into the table (after stripping the + CTID) and in the tuple header of the old row, which the + CTID pointed to, the cmax and xmax entries are set to the current command counter - and current transaction ID. Thus the old row is hidden and after + and current transaction ID. Thus the old row is hidden, and after the transaction committed the vacuum cleaner can really move it out. @@ -830,15 +769,12 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a; The above demonstrates how the rule system incorporates view - definitions into the original parse tree. In the second example a + definitions into the original query tree. In the second example, a simple SELECT from one view created a final - parse tree that is a join of 4 tables (unit is used twice with + query tree that is a join of 4 tables (unit was used twice with different names). - -Benefits - The benefit of implementing views with the rule system is, that the planner has all @@ -846,57 +782,51 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a; relationships between these tables plus the restrictive qualifications from the views plus the qualifications from the original query - in one single parse tree. And this is still the situation + in one single query tree. And this is still the situation when the original query is already a join over views. - Now the planner has to decide which is - the best path to execute the query. The more information + The planner has to decide which is + the best path to execute the query, and the more information the planner has, the better this decision can be. And the rule system as implemented in PostgreSQL ensures, that this is all information available about the query - up to now. + up to that point. - -What about updating a view? -viewsupdating +Updating a View What happens if a view is named as the target relation for an INSERT, UPDATE, or DELETE? After doing the substitutions described above, we will have a query tree in which the result - relation points at a subquery range table entry. This will not + relation points at a subquery range-table entry. This will not work, so the rewriter throws an error if it sees it has produced such a thing. - To change this we can define rules that modify the behavior of - non-SELECT queries. This is the topic of the - next section. + To change this, we can define rules that modify the behavior of + these kinds of commands. This is the topic of the next section. - -Rules on INSERT, UPDATE and DELETE - - -Differences from View Rules + +Rules on <command>INSERT</>, <command>UPDATE</>, and <command>DELETE</> - Rules that are defined ON INSERT, UPDATE and DELETE are totally - different from the view rules described in the previous - section. First, their CREATE RULE command - allows more: + Rules that are defined on INSERT, UPDATE, + and DELETE are significantly different from the view rules + described in the previous section. First, their CREATE + RULE command allows more: - They can have no action. + They are allowed to have no action. @@ -908,13 +838,13 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a; - The keyword INSTEAD is optional. + They can be INSTEAD or not. - The pseudo relations NEW and OLD become useful. + The pseudorelations NEW and OLD become useful. @@ -925,165 +855,141 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a; - Second, they don't modify the parse tree in place. Instead they - create zero or many new parse trees and can throw away the + Second, they don't modify the query tree in place. Instead they + create zero or more new query trees and can throw away the original one. - + -How These Rules Work +How Update Rules Work Keep the syntax -CREATE RULE rule_name AS ON event - TO object [WHERE rule_qualification] - DO [INSTEAD] [action | (actions) | NOTHING]; +CREATE RULE rule_name AS ON event + TO object [WHERE rule_qualification] + DO [INSTEAD] [action | (actions) | NOTHING]; in mind. In the following, update rules means rules that are defined - ON INSERT, UPDATE or DELETE. + on INSERT, UPDATE, or DELETE. Update rules get applied by the rule system when the result - relation and the command type of a parse tree are equal to the + relation and the command type of a query tree are equal to the object and event given in the CREATE RULE command. - For update rules, the rule system creates a list of parse trees. - Initially the parse tree list is empty. - There can be zero (NOTHING keyword), one or multiple actions. - To simplify, we look at a rule with one action. This rule - can have a qualification or not and it can be INSTEAD or not. + For update rules, the rule system creates a list of query trees. + Initially the query-tree list is empty. + There can be zero (NOTHING key word), one, or multiple actions. + To simplify, we will look at a rule with one action. This rule + can have a qualification or not and it can be INSTEAD or not. What is a rule qualification? It is a restriction that tells when the actions of the rule should be done and when not. This - qualification can only reference the NEW and/or OLD pseudo relations - which are basically the relation given as object (but with a + qualification can only reference the pseudorelations NEW and/or OLD, + which basically represent the relation that was given as object (but with a special meaning). - - So we have four cases that produce the following parse trees for + + So we have four cases that produce the following query trees for a one-action rule. - - - - - - No qualification and not INSTEAD: - - - - The parse tree from the rule action where the - original parse tree's qualification has been added. - - - - - - - - No qualification but INSTEAD: - - - - The parse tree from the rule action where the - original parse tree's qualification has been added. - - - - - + + + No qualification and not INSTEAD + + + the query tree from the rule action with the original query + tree's qualification added + + + - - - Qualification given and not INSTEAD: - - - - The parse tree from the rule action where the rule - qualification and the original parse tree's - qualification have been added. - - - - - + + No qualification but INSTEAD + + + the query tree from the rule action with the original query + tree's qualification added + + + - - - Qualification given and INSTEAD: - - - - The parse tree from the rule action where the rule - qualification and the original parse tree's - qualification have been added. - - + + Qualification given and not INSTEAD + + + the query tree from the rule action with the rule + qualification and the original query tree's qualification + added + + + - - - The original parse tree where the negated rule - qualification has been added. - - - - - - - - - Finally, if the rule is not INSTEAD, the unchanged original parse tree is - added to the list. Since only qualified INSTEAD rules already add the - original parse tree, we end up with either one or two output parse trees + + Qualification given and INSTEAD + + + the query tree from the rule action with the rule + qualification and the original query tree's qualification; and + the original query tree with the negated rule qualification + added + + + + + + Finally, if the rule is not INSTEAD, the unchanged original query tree is + added to the list. Since only qualified INSTEAD rules already add the + original query tree, we end up with either one or two output query trees for a rule with one action. - For ON INSERT rules, the original query (if not suppressed by INSTEAD) + For ON INSERT rules, the original query (if not suppressed by INSTEAD) is done before any actions added by rules. This allows the actions to - see the inserted row(s). But for ON UPDATE and ON - DELETE rules, the original query is done after the actions added by rules. + see the inserted row(s). But for ON UPDATE and ON + DELETE rules, the original query is done after the actions added by rules. This ensures that the actions can see the to-be-updated or to-be-deleted rows; otherwise, the actions might do nothing because they find no rows matching their qualifications. - The parse trees generated from rule actions are thrown into the - rewrite system again and maybe more rules get applied resulting - in more or less parse trees. - So the parse trees in the rule actions must have either another command type - or another result relation. Otherwise this recursive process will end up in a loop. - There is a compiled-in recursion limit of currently 100 iterations. - If after 100 iterations there are still update rules to apply the + The query trees generated from rule actions are thrown into the + rewrite system again, and maybe more rules get applied resulting + in more or less query trees. + So the query trees in the rule actions must have either a different command type + or a different result relation, otherwise, this recursive process will end up in a loop. + There is a fixed recursion limit of currently 100 iterations. + If after 100 iterations there are still update rules to apply, the rule system assumes a loop over multiple rule definitions and reports an error. - The parse trees found in the actions of the + The query trees found in the actions of the pg_rewrite system catalog are only templates. Since they can reference the range-table entries for - NEW and OLD, some substitutions have to be made before they can be - used. For any reference to NEW, the target list of the original + NEW and OLD, some substitutions have to be made before they can be + used. For any reference to NEW, the target list of the original query is searched for a corresponding entry. If found, that - entry's expression replaces the reference. Otherwise NEW means the - same as OLD (for an UPDATE) or is replaced by - NULL (for an INSERT). Any reference to OLD is - replaced by a reference to the range-table entry which is the + entry's expression replaces the reference. Otherwise, NEW means the + same as OLD (for an UPDATE) or is replaced by + a null value (for an INSERT). Any reference to OLD is + replaced by a reference to the range-table entry that is the result relation. - After we are done applying update rules, we apply view rules to the - produced parse tree(s). Views cannot insert new update actions so + After the system is done applying update rules, it applies view rules to the + produced query tree(s). Views cannot insert new update actions so there is no need to apply update rules to the output of view rewriting. @@ -1091,22 +997,22 @@ CREATE RULE rule_name AS ON event A First Rule Step by Step - We want to trace changes to the sl_avail column in the - shoelace_data relation. So we setup a log table + Say we want to trace changes to the sl_avail column in the + shoelace_data relation. So we set up a log table and a rule that conditionally writes a log entry when an UPDATE is performed on shoelace_data. CREATE TABLE shoelace_log ( - sl_name char(10), -- shoelace changed + sl_name text, -- shoelace changed sl_avail integer, -- new available value log_who text, -- who did it log_when timestamp -- when ); CREATE RULE log_shoelace AS ON UPDATE TO shoelace_data - WHERE NEW.sl_avail != OLD.sl_avail + WHERE NEW.sl_avail <> OLD.sl_avail DO INSERT INTO shoelace_log VALUES ( NEW.sl_name, NEW.sl_avail, @@ -1117,215 +1023,233 @@ CREATE RULE log_shoelace AS ON UPDATE TO shoelace_data - Now Al does + Now someone does: -al_bundy=> UPDATE shoelace_data SET sl_avail = 6 -al_bundy-> WHERE sl_name = 'sl7'; +UPDATE shoelace_data SET sl_avail = 6 WHERE sl_name = 'sl7'; - and we look at the log table. + and we look at the log table: -al_bundy=> SELECT * FROM shoelace_log; -sl_name |sl_avail|log_who|log_when -----------+--------+-------+-------------------------------- -sl7 | 6|Al |Tue Oct 20 16:14:45 1998 MET DST +SELECT * FROM shoelace_log; + + sl_name | sl_avail | log_who | log_when +---------+----------+---------+---------------------------------- + sl7 | 6 | Al | Tue Oct 20 16:14:45 1998 MET DST (1 row) + + That's what we expected. What happened in the background is the following. - The parser created the parse tree (this time the parts of the original - parse tree are highlighted because the base of operations is the - rule action for update rules). + The parser created the query tree -UPDATE shoelace_data SET sl_avail = 6 +UPDATE shoelace_data SET sl_avail = 6 FROM shoelace_data shoelace_data - WHERE bpchareq(shoelace_data.sl_name, 'sl7'); + WHERE shoelace_data.sl_name = 'sl7'; - There is a rule log_shoelace that is ON UPDATE with the rule + There is a rule log_shoelace that is ON UPDATE with the rule qualification expression -int4ne(NEW.sl_avail, OLD.sl_avail) +NEW.sl_avail <> OLD.sl_avail - and one action + and the action -INSERT INTO shoelace_log VALUES( +INSERT INTO shoelace_log VALUES ( *NEW*.sl_name, *NEW*.sl_avail, - current_user, current_timestamp) + current_user, current_timestamp ) FROM shoelace_data *NEW*, shoelace_data *OLD*; - This is a little strange-looking since you can't normally write - INSERT ... VALUES ... FROM. The FROM clause here is just to indicate - that there are range-table entries in the parse tree for *NEW* and *OLD*. - These are needed so that they can be referenced by variables in the - INSERT command's query tree. + (This looks a little strange since you can't normally write + INSERT ... VALUES ... FROM. The FROM + clause here is just to indicate that there are range-table entries + in the query tree for *NEW* and *OLD*. + These are needed so that they can be referenced by variables in + the INSERT command's query tree.) - The rule is a qualified non-INSTEAD rule, so the rule system - has to return two parse trees: the modified rule action and the original - parse tree. In the first step the range table of the original query is - incorporated into the rule's action parse tree. This results in + The rule is a qualified non-INSTEAD rule, so the rule system + has to return two query trees: the modified rule action and the original + query tree. In step 1, the range table of the original query is + incorporated into the rule's action query tree. This results in: -INSERT INTO shoelace_log VALUES( +INSERT INTO shoelace_log VALUES ( *NEW*.sl_name, *NEW*.sl_avail, - current_user, current_timestamp) + current_user, current_timestamp ) FROM shoelace_data *NEW*, shoelace_data *OLD*, shoelace_data shoelace_data; - In step 2 the rule qualification is added to it, so the result set - is restricted to rows where sl_avail changes. + In step 2, the rule qualification is added to it, so the result set + is restricted to rows where sl_avail changes: -INSERT INTO shoelace_log VALUES( +INSERT INTO shoelace_log VALUES ( *NEW*.sl_name, *NEW*.sl_avail, - current_user, current_timestamp) + current_user, current_timestamp ) FROM shoelace_data *NEW*, shoelace_data *OLD*, shoelace_data shoelace_data - WHERE int4ne(*NEW*.sl_avail, *OLD*.sl_avail); + WHERE *NEW*.sl_avail <> *OLD*.sl_avail; - This is even stranger-looking, since INSERT ... VALUES doesn't have - a WHERE clause either, but the planner and executor will have no + (This looks even stranger, since INSERT ... VALUES doesn't have + a WHERE clause either, but the planner and executor will have no difficulty with it. They need to support this same functionality - anyway for INSERT ... SELECT. + anyway for INSERT ... SELECT.) - In step 3 the original parse tree's qualification is added, - restricting the result set further to only the rows touched - by the original parse tree. + In step 3, the original query tree's qualification is added, + restricting the result set further to only the rows that would have been touched + by the original query: -INSERT INTO shoelace_log VALUES( +INSERT INTO shoelace_log VALUES ( *NEW*.sl_name, *NEW*.sl_avail, - current_user, current_timestamp) + current_user, current_timestamp ) FROM shoelace_data *NEW*, shoelace_data *OLD*, shoelace_data shoelace_data - WHERE int4ne(*NEW*.sl_avail, *OLD*.sl_avail) - AND bpchareq(shoelace_data.sl_name, 'sl7'); + WHERE *NEW*.sl_avail <> *OLD*.sl_avail + AND shoelace_data.sl_name = 'sl7'; + - Step 4 replaces NEW references by the target list entries from the - original parse tree or by the matching variable references - from the result relation. + + Step 4 replaces references to NEW by the target list entries from the + original query tree or by the matching variable references + from the result relation: -INSERT INTO shoelace_log VALUES( +INSERT INTO shoelace_log VALUES ( shoelace_data.sl_name, 6, - current_user, current_timestamp) + current_user, current_timestamp ) FROM shoelace_data *NEW*, shoelace_data *OLD*, shoelace_data shoelace_data - WHERE int4ne(6, *OLD*.sl_avail) - AND bpchareq(shoelace_data.sl_name, 'sl7'); + WHERE 6 <> *OLD*.sl_avail + AND shoelace_data.sl_name = 'sl7'; - Step 5 changes OLD references into result relation references. + + + + Step 5 changes OLD references into result relation references: -INSERT INTO shoelace_log VALUES( +INSERT INTO shoelace_log VALUES ( shoelace_data.sl_name, 6, - current_user, current_timestamp) + current_user, current_timestamp ) FROM shoelace_data *NEW*, shoelace_data *OLD*, shoelace_data shoelace_data - WHERE int4ne(6, shoelace_data.sl_avail) - AND bpchareq(shoelace_data.sl_name, 'sl7'); + WHERE 6 <> shoelace_data.sl_avail + AND shoelace_data.sl_name = 'sl7'; + - That's it. Since the rule is not INSTEAD, we also output the - original parse tree. In short, the output from the rule system - is a list of two parse trees that are the same as the statements: + + That's it. Since the rule is not INSTEAD, we also output the + original query tree. In short, the output from the rule system + is a list of two query trees that correspond to these statements: -INSERT INTO shoelace_log VALUES( +INSERT INTO shoelace_log VALUES ( shoelace_data.sl_name, 6, - current_user, current_timestamp) + current_user, current_timestamp ) FROM shoelace_data - WHERE 6 != shoelace_data.sl_avail + WHERE 6 <> shoelace_data.sl_avail AND shoelace_data.sl_name = 'sl7'; UPDATE shoelace_data SET sl_avail = 6 WHERE sl_name = 'sl7'; - These are executed in this order and that is exactly what - the rule defines. The substitutions and the qualifications - added ensure that if the original query would be, say, + These are executed in this order, and that is exactly what + the rule was meant to do. + + + + The substitutions and the added qualifications + ensure that, if the original query would be, say, UPDATE shoelace_data SET sl_color = 'green' WHERE sl_name = 'sl7'; - no log entry would get written. This - time the original parse tree does not contain a target list - entry for sl_avail, so NEW.sl_avail will get replaced by - shoelace_data.sl_avail resulting in the extra query + no log entry would get written. In that case, the original query + tree does not contain a target list entry for + sl_avail, so NEW.sl_avail will get + replaced by shoelace_data.sl_avail. Thus, the extra + command generated by the rule is -INSERT INTO shoelace_log VALUES( +INSERT INTO shoelace_log VALUES ( shoelace_data.sl_name, shoelace_data.sl_avail, - current_user, current_timestamp) + current_user, current_timestamp ) FROM shoelace_data - WHERE shoelace_data.sl_avail != shoelace_data.sl_avail + WHERE shoelace_data.sl_avail <> shoelace_data.sl_avail AND shoelace_data.sl_name = 'sl7'; - and that qualification will never be true. It will also - work if the original query modifies multiple rows. So if Al - would issue the command + and that qualification will never be true. + + + + It will also work if the original query modifies multiple rows. So + if someone issued the command UPDATE shoelace_data SET sl_avail = 0 WHERE sl_color = 'black'; - four rows in fact get updated (sl1, sl2, sl3 and sl4). - But sl3 already has sl_avail = 0. This time, the original - parse trees qualification is different and that results - in the extra parse tree + four rows in fact get updated (sl1, sl2, sl3, and sl4). + But sl3 already has sl_avail = 0. In this case, the original + query trees qualification is different and that results + in the extra query tree -INSERT INTO shoelace_log SELECT - shoelace_data.sl_name, 0, +INSERT INTO shoelace_log +SELECT shoelace_data.sl_name, 0, current_user, current_timestamp FROM shoelace_data - WHERE 0 != shoelace_data.sl_avail + WHERE 0 <> shoelace_data.sl_avail AND shoelace_data.sl_color = 'black'; - This parse tree will surely insert three new log entries. And - that's absolutely correct. + being generated by the rule. This query tree will surely insert + three new log entries. And that's absolutely correct. - Here we can see why it is important that the original parse tree - is executed last. If the UPDATE would have - been executed first, all the rows are already set to zero, so the - logging INSERT would not find any row where 0 - != shoelace_data.sl_avail. + Here we can see why it is important that the original query tree + is executed last. If the UPDATE had been + executed first, all the rows would have already been set to zero, so the + logging INSERT would not find any row where + 0 <> shoelace_data.sl_avail. - + Cooperation with Views +viewsupdating + A simple way to protect view relations from the mentioned - possibility that someone can try to INSERT, - UPDATE and DELETE on them is - to let those parse trees get thrown away. We create the rules + possibility that someone can try to run INSERT, + UPDATE, or DELETE on them is + to let those query trees get thrown away. So we create the rules CREATE RULE shoe_ins_protect AS ON INSERT TO shoe @@ -1336,18 +1260,18 @@ CREATE RULE shoe_del_protect AS ON DELETE TO shoe DO INSTEAD NOTHING; - If Al now tries to do any of these operations on the view + If someone now tries to do any of these operations on the view relation shoe, the rule system will - apply the rules. Since the rules have - no actions and are INSTEAD, the resulting list of - parse trees will be empty and the whole query will become + apply these rules. Since the rules have + no actions and are INSTEAD, the resulting list of + query trees will be empty and the whole query will become nothing because there is nothing left to be optimized or executed after the rule system is done with it. A more sophisticated way to use the rule system is to - create rules that rewrite the parse tree into one that + create rules that rewrite the query tree into one that does the right operation on the real tables. To do that on the shoelace view, we create the following rules: @@ -1360,12 +1284,13 @@ CREATE RULE shoelace_ins AS ON INSERT TO shoelace NEW.sl_avail, NEW.sl_color, NEW.sl_len, - NEW.sl_unit); + NEW.sl_unit + ); CREATE RULE shoelace_upd AS ON UPDATE TO shoelace DO INSTEAD - UPDATE shoelace_data SET - sl_name = NEW.sl_name, + UPDATE shoelace_data + SET sl_name = NEW.sl_name, sl_avail = NEW.sl_avail, sl_color = NEW.sl_color, sl_len = NEW.sl_len, @@ -1377,190 +1302,200 @@ CREATE RULE shoelace_del AS ON DELETE TO shoelace DELETE FROM shoelace_data WHERE sl_name = OLD.sl_name; + - Now there is a pack of shoelaces arriving in Al's shop and it has - a big part list. Al is not that good in calculating and so - we don't want him to manually update the shoelace view. - Instead we setup two little tables, one where he can - insert the items from the part list and one with a special - trick. The create commands for these are: + + Now assume that once in a while, a pack of shoelaces arrives at + the shop and a big parts list along with it. But you don't want + to manually update the shoelace view every + time. Instead we setup two little tables: one where you can + insert the items from the part list, and one with a special + trick. The creation commands for these are: CREATE TABLE shoelace_arrive ( - arr_name char(10), + arr_name text, arr_quant integer ); CREATE TABLE shoelace_ok ( - ok_name char(10), + ok_name text, ok_quant integer ); CREATE RULE shoelace_ok_ins AS ON INSERT TO shoelace_ok DO INSTEAD - UPDATE shoelace SET - sl_avail = sl_avail + NEW.ok_quant + UPDATE shoelace + SET sl_avail = sl_avail + NEW.ok_quant WHERE sl_name = NEW.ok_name; - Now Al can sit down and do whatever until + Now you can fill the table shoelace_arrive with + the data from the parts list: -al_bundy=> SELECT * FROM shoelace_arrive; -arr_name |arr_quant -----------+--------- -sl3 | 10 -sl6 | 20 -sl8 | 20 +SELECT * FROM shoelace_arrive; + + arr_name | arr_quant +----------+----------- + sl3 | 10 + sl6 | 20 + sl8 | 20 (3 rows) - is exactly what's on the part list. We take a quick look - at the current data, + Take a quick look at the current data: -al_bundy=> SELECT * FROM shoelace; -sl_name |sl_avail|sl_color |sl_len|sl_unit |sl_len_cm -----------+--------+----------+------+--------+--------- -sl1 | 5|black | 80|cm | 80 -sl2 | 6|black | 100|cm | 100 -sl7 | 6|brown | 60|cm | 60 -sl3 | 0|black | 35|inch | 88.9 -sl4 | 8|black | 40|inch | 101.6 -sl8 | 1|brown | 40|inch | 101.6 -sl5 | 4|brown | 1|m | 100 -sl6 | 0|brown | 0.9|m | 90 +SELECT * FROM shoelace; + + sl_name | sl_avail | sl_color | sl_len | sl_unit | sl_len_cm +----------+----------+----------+--------+---------+----------- + sl1 | 5 | black | 80 | cm | 80 + sl2 | 6 | black | 100 | cm | 100 + sl7 | 6 | brown | 60 | cm | 60 + sl3 | 0 | black | 35 | inch | 88.9 + sl4 | 8 | black | 40 | inch | 101.6 + sl8 | 1 | brown | 40 | inch | 101.6 + sl5 | 4 | brown | 1 | m | 100 + sl6 | 0 | brown | 0.9 | m | 90 (8 rows) - move the arrived shoelaces in + Now move the arrived shoelaces in: -al_bundy=> INSERT INTO shoelace_ok SELECT * FROM shoelace_arrive; +INSERT INTO shoelace_ok SELECT * FROM shoelace_arrive; - and check the results + and check the results: -al_bundy=> SELECT * FROM shoelace ORDER BY sl_name; -sl_name |sl_avail|sl_color |sl_len|sl_unit |sl_len_cm -----------+--------+----------+------+--------+--------- -sl1 | 5|black | 80|cm | 80 -sl2 | 6|black | 100|cm | 100 -sl7 | 6|brown | 60|cm | 60 -sl4 | 8|black | 40|inch | 101.6 -sl3 | 10|black | 35|inch | 88.9 -sl8 | 21|brown | 40|inch | 101.6 -sl5 | 4|brown | 1|m | 100 -sl6 | 20|brown | 0.9|m | 90 +SELECT * FROM shoelace ORDER BY sl_name; + + sl_name | sl_avail | sl_color | sl_len | sl_unit | sl_len_cm +----------+----------+----------+--------+---------+----------- + sl1 | 5 | black | 80 | cm | 80 + sl2 | 6 | black | 100 | cm | 100 + sl7 | 6 | brown | 60 | cm | 60 + sl4 | 8 | black | 40 | inch | 101.6 + sl3 | 10 | black | 35 | inch | 88.9 + sl8 | 21 | brown | 40 | inch | 101.6 + sl5 | 4 | brown | 1 | m | 100 + sl6 | 20 | brown | 0.9 | m | 90 (8 rows) -al_bundy=> SELECT * FROM shoelace_log; -sl_name |sl_avail|log_who|log_when -----------+--------+-------+-------------------------------- -sl7 | 6|Al |Tue Oct 20 19:14:45 1998 MET DST -sl3 | 10|Al |Tue Oct 20 19:25:16 1998 MET DST -sl6 | 20|Al |Tue Oct 20 19:25:16 1998 MET DST -sl8 | 21|Al |Tue Oct 20 19:25:16 1998 MET DST +SELECT * FROM shoelace_log; + + sl_name | sl_avail | log_who| log_when +---------+----------+--------+---------------------------------- + sl7 | 6 | Al | Tue Oct 20 19:14:45 1998 MET DST + sl3 | 10 | Al | Tue Oct 20 19:25:16 1998 MET DST + sl6 | 20 | Al | Tue Oct 20 19:25:16 1998 MET DST + sl8 | 21 | Al | Tue Oct 20 19:25:16 1998 MET DST (4 rows) + - It's a long way from the one INSERT ... SELECT to these - results. And its description will be the last in this - document (but not the last example :-). First there was the parser's output + + It's a long way from the one INSERT ... SELECT + to these results. And the description of the query-tree + transformation will be the last in this chapter. First, there is + the parser's output -INSERT INTO shoelace_ok SELECT - shoelace_arrive.arr_name, shoelace_arrive.arr_quant +INSERT INTO shoelace_ok +SELECT shoelace_arrive.arr_name, shoelace_arrive.arr_quant FROM shoelace_arrive shoelace_arrive, shoelace_ok shoelace_ok; - Now the first rule shoelace_ok_ins is applied and turns it + Now the first rule shoelace_ok_ins is applied and turns this into -UPDATE shoelace SET - sl_avail = int4pl(shoelace.sl_avail, shoelace_arrive.arr_quant) +UPDATE shoelace + SET sl_avail = shoelace.sl_avail + shoelace_arrive.arr_quant FROM shoelace_arrive shoelace_arrive, shoelace_ok shoelace_ok, shoelace_ok *OLD*, shoelace_ok *NEW*, shoelace shoelace - WHERE bpchareq(shoelace.sl_name, showlace_arrive.arr_name); + WHERE shoelace.sl_name = shoelace_arrive.arr_name; and throws away the original INSERT on shoelace_ok. This rewritten query is passed to - the rule system again and the second applied rule - shoelace_upd produced + the rule system again, and the second applied rule + shoelace_upd produces -UPDATE shoelace_data SET - sl_name = shoelace.sl_name, - sl_avail = int4pl(shoelace.sl_avail, shoelace_arrive.arr_quant), +UPDATE shoelace_data + SET sl_name = shoelace.sl_name, + sl_avail = shoelace.sl_avail + shoelace_arrive.arr_quant, sl_color = shoelace.sl_color, sl_len = shoelace.sl_len, sl_unit = shoelace.sl_unit FROM shoelace_arrive shoelace_arrive, shoelace_ok shoelace_ok, shoelace_ok *OLD*, shoelace_ok *NEW*, shoelace shoelace, shoelace *OLD*, - shoelace *NEW*, shoelace_data showlace_data - WHERE bpchareq(shoelace.sl_name, showlace_arrive.arr_name) - AND bpchareq(shoelace_data.sl_name, shoelace.sl_name); + shoelace *NEW*, shoelace_data shoelace_data + WHERE shoelace.sl_name = shoelace_arrive.arr_name + AND shoelace_data.sl_name = shoelace.sl_name; - Again it's an INSTEAD rule and the previous parse tree is trashed. + Again it's an INSTEAD rule and the previous query tree is trashed. Note that this query still uses the view shoelace. - But the rule system isn't finished with this loop so it continues - and applies the _RETURN rule on it and we get + But the rule system isn't finished with this step, so it continues + and applies the _RETURN rule on it, and we get -UPDATE shoelace_data SET - sl_name = s.sl_name, - sl_avail = int4pl(s.sl_avail, shoelace_arrive.arr_quant), +UPDATE shoelace_data + SET sl_name = s.sl_name, + sl_avail = s.sl_avail + shoelace_arrive.arr_quant, sl_color = s.sl_color, sl_len = s.sl_len, sl_unit = s.sl_unit FROM shoelace_arrive shoelace_arrive, shoelace_ok shoelace_ok, shoelace_ok *OLD*, shoelace_ok *NEW*, shoelace shoelace, shoelace *OLD*, - shoelace *NEW*, shoelace_data showlace_data, + shoelace *NEW*, shoelace_data shoelace_data, shoelace *OLD*, shoelace *NEW*, shoelace_data s, unit u - WHERE bpchareq(s.sl_name, showlace_arrive.arr_name) - AND bpchareq(shoelace_data.sl_name, s.sl_name); + WHERE s.sl_name = shoelace_arrive.arr_name + AND shoelace_data.sl_name = s.sl_name; - Again an update rule has been applied and so the wheel - turns on and we are in rewrite round 3. This time rule - log_shoelace gets applied, producing the extra - parse tree + Finally, the rule log_shoelace gets applied, + producing the extra query tree -INSERT INTO shoelace_log SELECT - s.sl_name, - int4pl(s.sl_avail, shoelace_arrive.arr_quant), +INSERT INTO shoelace_log +SELECT s.sl_name, + s.sl_avail + shoelace_arrive.arr_quant, current_user, current_timestamp FROM shoelace_arrive shoelace_arrive, shoelace_ok shoelace_ok, shoelace_ok *OLD*, shoelace_ok *NEW*, shoelace shoelace, shoelace *OLD*, - shoelace *NEW*, shoelace_data showlace_data, + shoelace *NEW*, shoelace_data shoelace_data, shoelace *OLD*, shoelace *NEW*, shoelace_data s, unit u, shoelace_data *OLD*, shoelace_data *NEW* shoelace_log shoelace_log - WHERE bpchareq(s.sl_name, showlace_arrive.arr_name) - AND bpchareq(shoelace_data.sl_name, s.sl_name); - AND int4ne(int4pl(s.sl_avail, shoelace_arrive.arr_quant), s.sl_avail); + WHERE s.sl_name = shoelace_arrive.arr_name + AND shoelace_data.sl_name = s.sl_name + AND (s.sl_avail + shoelace_arrive.arr_quant) <> s.sl_avail; After that the rule system runs out of rules and returns the - generated parse trees. - So we end up with two final parse trees that are equal to the + generated query trees. + + + + So we end up with two final query trees that are equivalent to the SQL statements -INSERT INTO shoelace_log SELECT - s.sl_name, +INSERT INTO shoelace_log +SELECT s.sl_name, s.sl_avail + shoelace_arrive.arr_quant, current_user, current_timestamp @@ -1568,10 +1503,10 @@ INSERT INTO shoelace_log SELECT shoelace_data s WHERE s.sl_name = shoelace_arrive.arr_name AND shoelace_data.sl_name = s.sl_name - AND s.sl_avail + shoelace_arrive.arr_quant != s.sl_avail; + AND s.sl_avail + shoelace_arrive.arr_quant <> s.sl_avail; -UPDATE shoelace_data SET - sl_avail = shoelace_data.sl_avail + shoelace_arrive.arr_quant +UPDATE shoelace_data + SET sl_avail = shoelace_data.sl_avail + shoelace_arrive.arr_quant FROM shoelace_arrive shoelace_arrive, shoelace_data shoelace_data, shoelace_data s @@ -1587,13 +1522,13 @@ UPDATE shoelace_data SET There is a little detail that's a bit ugly. Looking at the two - queries turns out, that the shoelace_data + queries, it turns out that the shoelace_data relation appears twice in the range table where it could definitely be reduced to one. The planner does not handle it and so the execution plan for the rule systems output of the INSERT will be - + Nested Loop -> Merge Join -> Seq Scan @@ -1603,11 +1538,11 @@ Nested Loop -> Sort -> Seq Scan on shoelace_arrive -> Seq Scan on shoelace_data - + while omitting the extra range table entry would result in a - + Merge Join -> Seq Scan -> Sort @@ -1615,41 +1550,33 @@ Merge Join -> Seq Scan -> Sort -> Seq Scan on shoelace_arrive - + - that totally produces the same entries in the log relation. Thus, - the rule system caused one extra scan on the - shoelace_data relation that is absolutely not - necessary. And the same obsolete scan is done once more in the + which produces exactly the same entries in the log table. Thus, + the rule system caused one extra scan on the table + shoelace_data that is absolutely not + necessary. And the same redundant scan is done once more in the UPDATE. But it was a really hard job to make that all possible at all. - A final demonstration of the PostgreSQL - rule system and its power. There is a cute blonde that - sells shoelaces. And what Al could never realize, she's not - only cute, she's smart too - a little too smart. Thus, it - happens from time to time that Al orders shoelaces that - are absolutely not sellable. This time he ordered 1000 pairs - of magenta shoelaces and since another kind is currently not - available but he committed to buy some, he also prepared - his database for pink ones. + Now we make a final demonstration of the + PostgreSQL rule system and its power. + Say you add some shoelaces with extraordinary colors to your + database: -al_bundy=> INSERT INTO shoelace VALUES -al_bundy-> ('sl9', 0, 'pink', 35.0, 'inch', 0.0); -al_bundy=> INSERT INTO shoelace VALUES -al_bundy-> ('sl10', 1000, 'magenta', 40.0, 'inch', 0.0); +INSERT INTO shoelace VALUES ('sl9', 0, 'pink', 35.0, 'inch', 0.0); +INSERT INTO shoelace VALUES ('sl10', 1000, 'magenta', 40.0, 'inch', 0.0); - Since this happens often, we must lookup for shoelace entries, - that fit for absolutely no shoe sometimes. We could do that in - a complicated statement every time, or we can setup a view - for it. The view for this is + We would like to make a view to check which + shoelace entries do not fit any shoe in color. + The view for this is -CREATE VIEW shoelace_obsolete AS +CREATE VIEW shoelace_mismatch AS SELECT * FROM shoelace WHERE NOT EXISTS (SELECT shoename FROM shoe WHERE slcolor = sl_color); @@ -1657,82 +1584,80 @@ CREATE VIEW shoelace_obsolete AS Its output is -al_bundy=> SELECT * FROM shoelace_obsolete; -sl_name |sl_avail|sl_color |sl_len|sl_unit |sl_len_cm -----------+--------+----------+------+--------+--------- -sl9 | 0|pink | 35|inch | 88.9 -sl10 | 1000|magenta | 40|inch | 101.6 - +SELECT * FROM shoelace_mismatch; - For the 1000 magenta shoelaces we must debit Al before we can - throw 'em away, but that's another problem. The pink entry we delete. + sl_name | sl_avail | sl_color | sl_len | sl_unit | sl_len_cm +---------+----------+----------+--------+---------+----------- + sl9 | 0 | pink | 35 | inch | 88.9 + sl10 | 1000 | magenta | 40 | inch | 101.6 + + + + + Now we want to set it up so that mismatching shoelaces that are + not in stock are deleted from the database. To make it a little harder for PostgreSQL, we don't delete it directly. Instead we create one more view -CREATE VIEW shoelace_candelete AS - SELECT * FROM shoelace_obsolete WHERE sl_avail = 0; +CREATE VIEW shoelace_can_delete AS + SELECT * FROM shoelace_mismatch WHERE sl_avail = 0; and do it this way: DELETE FROM shoelace WHERE EXISTS - (SELECT * FROM shoelace_candelete + (SELECT * FROM shoelace_can_delete WHERE sl_name = shoelace.sl_name); Voilą: -al_bundy=> SELECT * FROM shoelace; -sl_name |sl_avail|sl_color |sl_len|sl_unit |sl_len_cm -----------+--------+----------+------+--------+--------- -sl1 | 5|black | 80|cm | 80 -sl2 | 6|black | 100|cm | 100 -sl7 | 6|brown | 60|cm | 60 -sl4 | 8|black | 40|inch | 101.6 -sl3 | 10|black | 35|inch | 88.9 -sl8 | 21|brown | 40|inch | 101.6 -sl10 | 1000|magenta | 40|inch | 101.6 -sl5 | 4|brown | 1|m | 100 -sl6 | 20|brown | 0.9|m | 90 +SELECT * FROM shoelace; + + sl_name | sl_avail | sl_color | sl_len | sl_unit | sl_len_cm +---------+----------+----------+--------+---------+----------- + sl1 | 5 | black | 80 | cm | 80 + sl2 | 6 | black | 100 | cm | 100 + sl7 | 6 | brown | 60 | cm | 60 + sl4 | 8 | black | 40 | inch | 101.6 + sl3 | 10 | black | 35 | inch | 88.9 + sl8 | 21 | brown | 40 | inch | 101.6 + sl10 | 1000 | magenta | 40 | inch | 101.6 + sl5 | 4 | brown | 1 | m | 100 + sl6 | 20 | brown | 0.9 | m | 90 (9 rows) + - A DELETE on a view, with a subselect qualification that + + A DELETE on a view, with a subquery qualification that in total uses 4 nesting/joined views, where one of them - itself has a subselect qualification containing a view + itself has a subquery qualification containing a view and where calculated view columns are used, gets rewritten into - one single parse tree that deletes the requested data + one single query tree that deletes the requested data from a real table. - I think there are only a few situations out in the real - world, where such a construct is necessary. But - it makes me feel comfortable that it works. + There are probably only a few situations out in the real world + where such a construct is necessary. But it makes you feel + comfortable that it works. - - - The truth is: - - Doing this I found one more bug while writing this document. - But after fixing that I was a little amazed that it works at all. - - - -Rules and Permissions + +Rules and Privileges Due to rewriting of queries by the PostgreSQL rule system, other tables/views than those used in the original - query get accessed. Using update rules, this can include write access + query get accessed. When update rules are used, this can include write access to tables. @@ -1743,9 +1668,9 @@ sl6 | 20|brown | 0.9|m | 90 The PostgreSQL rule system changes the behavior of the default access control system. Relations that are used due to rules get checked against the - permissions of the rule owner, not the user invoking the rule. - This means, that a user does only need the required permissions - for the tables/views he names in his queries. + privileges of the rule owner, not the user invoking the rule. + This means that a user only needs the required privileges + for the tables/views that he names explicitly in his queries. @@ -1754,67 +1679,62 @@ sl6 | 20|brown | 0.9|m | 90 He can construct the following: -CREATE TABLE phone_data (person text, phone text, private bool); +CREATE TABLE phone_data (person text, phone text, private boolean); CREATE VIEW phone_number AS SELECT person, phone FROM phone_data WHERE NOT private; GRANT SELECT ON phone_number TO secretary; Nobody except him (and the database superusers) can access the - phone_data table. But due to the GRANT, the secretary can - SELECT from the phone_number view. The rule - system will rewrite the SELECT from - phone_number into a SELECT from phone_data and - add the qualification that only entries where private is false are - wanted. Since the user is the owner of phone_number, the read - access to phone_data is now checked against his permissions and - the query is considered granted. The check for accessing - phone_number is also performed, but this is done against the - invoking user, so nobody but the user and the secretary can use - it. + phone_data table. But because of the GRANT, + the secretary can run a SELECT on the + phone_number view. The rule system will rewrite the + SELECT from phone_number into a + SELECT from phone_data and add the + qualification that only entries where private is false + are wanted. Since the user is the owner of + phone_number and therefore the owner of the rule, the + read access to phone_data is now checked against his + privileges and the query is permitted. The check for accessing + phone_number is also performed, but this is done + against the invoking user, so nobody but the user and the + secretary can use it. - The permissions are checked rule by rule. So the secretary is for now the + The privileges are checked rule by rule. So the secretary is for now the only one who can see the public phone numbers. But the secretary can setup - another view and grant access to that to public. Then, anyone - can see the phone_number data through the secretaries view. + another view and grant access to that to the public. Then, anyone + can see the phone_number data through the secretary's view. What the secretary cannot do is to create a view that directly - accesses phone_data (actually he can, but it will not work since - every access aborts the transaction during the permission checks). + accesses phone_data. (Actually he can, but it will not work since + every access will be denied during the permission checks.) And as soon as the user will notice, that the secretary opened - his phone_number view, he can REVOKE his access. Immediately any - access to the secretaries view will fail. + his phone_number view, he can revoke his access. Immediately, any + access to the secretary's view would fail. - Someone might think that this rule by rule checking is a security - hole, but in fact it isn't. If this would not work, the secretary - could setup a table with the same columns as phone_number and + One might think that this rule-by-rule checking is a security + hole, but in fact it isn't. But if it did not work this way, the secretary + could set up a table with the same columns as phone_number and copy the data to there once per day. Then it's his own data and he can grant access to everyone he wants. A - GRANT means I trust you. + GRANT command means, I trust you. If someone you trust does the thing above, it's time to - think it over and then REVOKE. + think it over and then use REVOKE. - This mechanism does also work for update rules. In the examples - of the previous section, the owner of the tables in Al's database - could GRANT SELECT, INSERT, UPDATE and DELETE on the shoelace view to al. - But only SELECT on shoelace_log. The rule action to write log entries - will still be executed successfully. And Al could see the log entries. - But he cannot create fake entries, nor could he manipulate or remove - existing ones. - - - Warning - - GRANT ALL currently includes RULE permission. This means the granted - user could drop the rule, do the changes and reinstall it. I think - this should get changed quickly. - - + This mechanism also works for update rules. In the examples of + the previous section, the owner of the tables in the example + database could grant the privileges SELECT, + INSERT, UPDATE, and DELETE on + the shoelace view to someone else, but only + SELECT on shoelace_log. The rule action to + write log entries will still be executed successfully, and that + other user could see the log entries. But he cannot create fake + entries, nor could he manipulate or remove existing ones. @@ -1824,21 +1744,20 @@ GRANT SELECT ON phone_number TO secretary; The PostgreSQL server returns a command status string, such as INSERT 149592 1, for each - query it receives. This is simple enough when there are no rules + command it receives. This is simple enough when there are no rules involved, but what happens when the query is rewritten by rules? - As of PostgreSQL 7.3, rules affect the - command status as follows: + Rules affect the command status as follows: - + - If there is no unconditional INSTEAD rule for the query, then + If there is no unconditional INSTEAD rule for the query, then the originally given query will be executed, and its command status will be returned as usual. (But note that if there were - any conditional INSTEAD rules, the negation of their qualifications + any conditional INSTEAD rules, the negation of their qualifications will have been added to the original query. This may reduce the number of rows it processes, and if so the reported status will be affected.) @@ -1847,26 +1766,30 @@ GRANT SELECT ON phone_number TO secretary; - If there is any unconditional INSTEAD rule for the query, then + If there is any unconditional INSTEAD rule for the query, then the original query will not be executed at all. In this case, the server will return the command status for the last query - that was inserted by an INSTEAD rule (conditional or - unconditional) and is of the same type + that was inserted by an INSTEAD rule (conditional or + unconditional) and is of the same command type (INSERT, UPDATE, or DELETE) as the original query. If no query meeting those requirements is added by any rule, then the returned command status shows the original query type and - zeroes for the tuple-count and OID fields. + zeroes for the row-count and OID fields. - + + + (This system was established in PostgreSQL 7.3. In versions + before that, the command status might show different results when + rules exist.) - The programmer can ensure that any desired INSTEAD rule is the one + The programmer can ensure that any desired INSTEAD rule is the one that sets the command status in the second case, by giving it the alphabetically last rule name among the active rules, so that it - fires last. + gets applied last. @@ -1876,39 +1799,40 @@ GRANT SELECT ON phone_number TO secretary; Many things that can be done using triggers can also be implemented using the PostgreSQL - rule system. What currently cannot be implemented by - rules are some kinds of constraints. It is possible, - to place a qualified rule that rewrites a query to NOTHING + rule system. One of the things that cannot be implemented by + rules are some kinds of constraints, especially foreign keys. It is possible + to place a qualified rule that rewrites a command to NOTHING if the value of a column does not appear in another table. But then the data is silently thrown away and that's not a good idea. If checks for valid values are required, and in the case of an invalid value an error message should - be generated, it must be done by a trigger for now. + be generated, it must be done by a trigger. - On the other hand a trigger that is fired on - INSERT on a view can do the same as a rule, put + On the other hand, a trigger that is fired on + INSERT on a view can do the same as a rule: put the data somewhere else and suppress the insert in the view. But it cannot do the same thing on UPDATE or DELETE, because there is no real data in the - view relation that could be scanned and thus the trigger would + view relation that could be scanned, and thus the trigger would never get called. Only a rule will help. For the things that can be implemented by both, it depends on the usage of the database, which is the best. - A trigger is fired for any row affected once. A rule manipulates - the parse tree or generates an additional one. So if many + A trigger is fired for any affected row once. A rule manipulates + the query tree or generates an additional one. So if many rows are affected in one statement, a rule issuing one extra - query would usually do a better job than a trigger that is - called for any single row and must execute his operations - this many times. + command would usually do a better job than a trigger that is + called for every single row and must execute its operations + many times. - For example: There are two tables + Here we show an example of how the choice of rules versus triggers + plays out in one situation. There are two tables: CREATE TABLE computer ( @@ -1922,35 +1846,36 @@ CREATE TABLE software ( ); - Both tables have many - thousands of rows and the index on hostname is unique. - The hostname column contains the full qualified domain - name of the computer. The rule/trigger should constraint - delete rows from software that reference the deleted host. - Since the trigger is called for each individual row - deleted from computer, it can use the statement + Both tables have many thousands of rows and the indexes on + hostname are unique. The rule or trigger should + implement a constraint that deletes rows from software + that reference a deleted computer. The trigger would use this command: DELETE FROM software WHERE hostname = $1; - in a prepared and saved plan and pass the hostname in - the parameter. The rule would be written as + Since the trigger is called for each individual row deleted from + computer, it can prepare and save the plan for this + command and pass the hostname value in the + parameter. The rule would be written as CREATE RULE computer_del AS ON DELETE TO computer DO DELETE FROM software WHERE hostname = OLD.hostname; + + Now we look at different types of deletes. In the case of a DELETE FROM computer WHERE hostname = 'mypc.local.net'; - the table computer is scanned by index (fast) and the - query issued by the trigger would also be an index scan (fast too). - The extra query from the rule would be a + the table computer is scanned by index (fast), and the + command issued by the trigger would also use an index scan (also fast). + The extra command from the rule would be DELETE FROM software WHERE computer.hostname = 'mypc.local.net' @@ -1960,72 +1885,92 @@ DELETE FROM software WHERE computer.hostname = 'mypc.local.net' Since there are appropriate indexes setup, the planner will create a plan of - + Nestloop -> Index Scan using comp_hostidx on computer -> Index Scan using soft_hostidx on software - + So there would be not that much difference in speed between - the trigger and the rule implementation. With the next delete - we want to get rid of all the 2000 computers where the hostname starts - with 'old'. There are two possible queries to do that. One is + the trigger and the rule implementation. + + + + With the next delete we want to get rid of all the 2000 computers + where the hostname starts with + old. There are two possible commands to do that. One + is DELETE FROM computer WHERE hostname >= 'old' AND hostname < 'ole' - Where the plan for the rule query will be a + The command added by the rule will be +DELETE FROM software WHERE computer.hostname >= 'old' AND computer.hostname < 'ole' + AND software.hostname = computer.hostname; + + + with the plan + + Hash Join -> Seq Scan on software -> Hash -> Index Scan using comp_hostidx on computer - + - The other possible query is a + The other possible command is DELETE FROM computer WHERE hostname ~ '^old'; - with the execution plan + which results in the following executing plan for the command + added by the rule: - + Nestloop -> Index Scan using comp_hostidx on computer -> Index Scan using soft_hostidx on software - + This shows, that the planner does not realize that the - qualification for the hostname on computer could also be - used for an index scan on software when there are - multiple qualification expressions combined with AND, what - he does in the regexp version of the query. The trigger will - get invoked once for any of the 2000 old computers that - have to be deleted and that will result in one index scan - over computer and 2000 index scans for the software. The - rule implementation will do it with two queries over indexes. - And it depends on the overall size of the software table if - the rule will still be faster in the sequential scan situation. 2000 - query executions over the SPI manager take some time, even - if all the index blocks to look them up will soon appear in - the cache. + qualification for hostname in + computer could also be used for an index scan on + software when there are multiple qualification + expressions combined with AND, which is what it does + in the regular-expression version of the command. The trigger will + get invoked once for each of the 2000 old computers that have to be + deleted, and that will result in one index scan over + computer and 2000 index scans over + software. The rule implementation will do it with two + commands that use indexes. And it depends on the overall size of + the table software whether the rule will still be faster in the + sequential scan situation. 2000 command executions from the trigger over the SPI + manager take some time, even if all the index blocks will soon be in the cache. - The last query we look at is a + The last command we look at is DELETE FROM computer WHERE manufacurer = 'bim'; Again this could result in many rows to be deleted from - computer. So the trigger will again fire many queries into - the executor. But the rule plan will again be the nested loop over - two index scans. Only using another index on computer: + computer. So the trigger will again run many commands + through the executor. The command generated by the rule will be + + +DELETE FROM software WHERE computer.manufacurer = 'bim' + AND software.hostname = computer.hostname; + + + The plan for that command will again be the nested loop over two + index scans, only using a different index on computer: Nestloop @@ -2033,18 +1978,13 @@ Nestloop -> Index Scan using soft_hostidx on software - resulting from the rules query - - -DELETE FROM software WHERE computer.manufacurer = 'bim' - AND software.hostname = computer.hostname; - - - In any of these cases, the extra queries from the rule system will be - more or less independent from the number of affected rows - in a query. + In any of these cases, the extra commands from the rule system + will be more or less independent from the number of affected rows + in a command. + Another situation is cases on UPDATE where it depends on the change of an attribute if an action should be performed or @@ -2068,13 +2008,12 @@ DELETE FROM software WHERE computer.manufacurer = 'bim' if the attribute isn't touched. So the rule, qualified or not, will only do its scans if there ever could be something to do. +]]> - Rules will only be significantly slower than triggers if - their actions result in large and bad qualified joins, a situation - where the planner fails. They are a big hammer. - Using a big hammer without caution can cause big damage. But - used with the right touch, they can hit any nail on the head. + The summary is, rules will only be significantly slower than + triggers if their actions result in large and badly qualified + joins, a situation where the planner fails.