Skip to content
Snippets Groups Projects
rules.sgml 69.6 KiB
Newer Older
<!-- $Header: /cvsroot/pgsql/doc/src/sgml/rules.sgml,v 1.23 2002/04/19 23:13:53 tgl Exp $ -->
<Title>The Rule System</Title>
 <indexterm zone="rules">
  <primary>rules</primary>
 </indexterm>

   <note>
    <title>Author</title>
    <para>
     Written by Jan Wieck.  Updates for 7.1 by Tom Lane.
    </para>
   </note>

Peter Eisentraut's avatar
Peter Eisentraut committed
   <sect1 id="rules-intro">
    <title>Introduction</title>

     Production rule systems are conceptually simple, but
     there are many subtle points involved in actually using
     the theoretical foundations of the <ProductName>PostgreSQL</ProductName>
<XRef LinkEnd="STON90b">.
</Para>

<Para>
     Some other database systems define active database rules. These
     are usually stored procedures and triggers and are implemented
     in <ProductName>PostgreSQL</ProductName> as functions and triggers.
     The query rewrite rule system (the <firstterm>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 
<XRef LinkEnd="ONG90">
<XRef LinkEnd="STON90b">.
Peter Eisentraut's avatar
Peter Eisentraut committed

  </sect1>


<Para>
    To understand how the rule system works it is necessary to know
    when it is invoked and what its input and results are.
    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 <FileName>pg_rewrite</FileName> catalog, which are
    query trees too with some extra information, and creates zero or many
    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 <Acronym>SQL</Acronym> statement.
    Now what is a query tree? It is an internal representation of an
    <Acronym>SQL</Acronym> statement where the single parts that built
    it are stored separately. These query trees are visible when starting
    the <ProductName>PostgreSQL</ProductName> backend with debug level 4
    and typing queries into the interactive backend interface. The rule
    actions in the <FileName>pg_rewrite</FileName> system catalog are
    also stored as query trees. They are not formatted like the debug
    output, but they contain exactly the same information.
</Para>

<Para>
    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 
    <Acronym>SQL</Acronym> 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.
</Para>

<Sect2>
<Title>The Parts of a Query tree</Title>

<Para>
    When reading the <Acronym>SQL</Acronym> representations of the 
    query trees in this document 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
    </Term>
    <ListItem>
    <Para>
        This is a simple value telling which command
	(SELECT, INSERT, UPDATE, DELETE) produced the parse tree.
    </Para>
    </ListItem>
    </VarListEntry>

    <VarListEntry>
    <Term>
      <indexterm><primary>range table</></>
        The range table is a list of relations that are used in the query.
	In a SELECT statement these are the relations given after
        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
	are duplicate names as it would in an <Acronym>SQL</Acronym>
	statement. This can happen after the range tables of rules
	have been merged in. The examples in this document will not have
	this situation.
    </Para>
    </ListItem>
    </VarListEntry>

    <VarListEntry>
    <Term>
        This is an index into the range table that identifies the
	relation where the results of the query go.
    </Para>

    <Para>
	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 separately
	here.
    </Para>

    <Para>
        On INSERT, UPDATE and DELETE queries the result relation
	is the table (or view!) where the changes take effect.
    </Para>
    </ListItem>
    </VarListEntry>

    <VarListEntry>
    <Term>
        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.)
        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
        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 SELECT clause in INSERT ... SELECT.
	Missing columns of the result relation will be filled in by the
	planner with a constant NULL expression.
        In UPDATE queries, 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 add 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.
        Every entry in the target list contains an expression that can
	be a constant value, a variable pointing to an attribute of one
	of the relations in the range table, a parameter, or an expression
	tree made of function calls, constants, variables, operators etc.
    </Para>
    </ListItem>
    </VarListEntry>

    <VarListEntry>
    <Term>
        the qualification
    </Term>
    <ListItem>
    <Para>
        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
	(INSERT, UPDATE, DELETE or SELECT) for the final result row should be
	executed or not. It is the WHERE clause of an
	<Acronym>SQL</Acronym> statement.
    </Para>
    </ListItem>
    </VarListEntry>

    <VarListEntry>
    <Term>
        the join tree
    </Term>
    <ListItem>
    <Para>
        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.
    </Para>
    </ListItem>
    </VarListEntry>

    <VarListEntry>
    <Term>
        the others
    </Term>
    <ListItem>
    <Para>
        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
	doesn't have much to do with the fundamentals of the rule
    </Para>
    </ListItem>
    </VarListEntry>

</VariableList>
<Title>Views and the Rule System</Title>
<indexterm zone="rules-views"><primary>rules</><secondary>and views</></>
<Title>Implementation of Views in <ProductName>PostgreSQL</ProductName></Title>
    Views in <ProductName>PostgreSQL</ProductName> are implemented
    using the rule system. In fact there is absolutely no difference
    between a

<ProgramListing>
CREATE VIEW myview AS SELECT * FROM mytab;
</ProgramListing>
    
    compared against the two commands

<ProgramListing>
CREATE TABLE myview (<Replaceable>same attribute list as for mytab</Replaceable>);
CREATE RULE "_RETURN" AS ON SELECT TO myview DO INSTEAD
    SELECT * FROM mytab;
</ProgramListing>
    
    because this is exactly what the CREATE VIEW command does internally.
    This has some side effects. One of them is that
    the information about a view in the <ProductName>PostgreSQL</ProductName>
    system catalogs is exactly the same as it is for a table. So for the
    query 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.
</Para>
</Sect2>

<Sect2>
<Title>How SELECT Rules Work</Title>
    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 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.
</Para>

<Para>
    The examples for this document 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 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 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.
</Para>

<Para>
    The database needed to play with the examples is named <literal>al_bundy</literal>.
    You'll see soon why this is the database name. And it needs the
    procedural language <application>PL/pgSQL</> installed, because
    we need a little min() function returning 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;
    The real tables we need in the first two rule system descriptions
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
);
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
);
CREATE TABLE unit (
    un_name    char(8),       -- the primary key
    un_fact    float          -- factor to transform to cm
);
</ProgramListing>

    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.
</Para>
CREATE VIEW shoe AS
    SELECT sh.shoename,
           sh.sh_avail,
           sh.slcolor,
           sh.slminlen,
           sh.slminlen * un.un_fact AS slminlen_cm,
           sh.slmaxlen,
           sh.slmaxlen * un.un_fact AS slmaxlen_cm,
           sh.slunit
      FROM shoe_data sh, unit un
     WHERE sh.slunit = un.un_name;

CREATE VIEW shoelace AS
    SELECT s.sl_name,
           s.sl_avail,
           s.sl_color,
           s.sl_len,
           s.sl_unit,
           s.sl_len * u.un_fact AS sl_len_cm
      FROM shoelace_data s, unit u
     WHERE s.sl_unit = u.un_name;

CREATE VIEW shoe_ready AS
    SELECT rsh.shoename,
           rsh.sh_avail,
           rsl.sl_name,
           rsl.sl_avail,
           min(rsh.sh_avail, rsl.sl_avail) AS total_avail
      FROM shoe rsh, shoelace rsl
     WHERE rsl.sl_color = rsh.slcolor
       AND rsl.sl_len_cm >= rsh.slminlen_cm
       AND rsl.sl_len_cm <= rsh.slmaxlen_cm;
</ProgramListing>

    The CREATE VIEW command for the <Filename>shoelace</Filename> 
    view (which is the simplest one we have)
    will create a relation shoelace and an entry 
    in <FileName>pg_rewrite</FileName>
    that tells that there is a 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
    SELECT statement in the view creation command.
    
    <Note>
    <Title>Note</Title>
    <Para>
    The two extra range
    table entries for NEW and OLD (named *NEW* and *CURRENT* for
    historical reasons in the printed query tree) you can see in
    the <Filename>pg_rewrite</Filename> entry aren't of interest
    for SELECT rules.
    </Para>
    </Note>

    Now we populate <Filename>unit</Filename>, <Filename>shoe_data</Filename>
    and <Filename>shoelace_data</Filename> and Al types the first 
    SELECT in his life:

<ProgramListing>
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
(8 rows)
</ProgramListing>

    It's the simplest SELECT Al can do on our views, so we take this
    to explain the basics of view rules.
    The <literal>SELECT * FROM shoelace</literal> was interpreted by the parser and
    produced the parse tree
SELECT shoelace.sl_name, shoelace.sl_avail,
       shoelace.sl_color, shoelace.sl_len,
       shoelace.sl_unit, shoelace.sl_len_cm
  FROM shoelace shoelace;
</ProgramListing>

    and this is given to the rule system. The rule system walks through the
    range table and checks if there are rules in <Filename>pg_rewrite</Filename>
    for any relation. When processing the range table entry for
    <Filename>shoelace</Filename> (the only one up to now) it finds the
    <literal>_RETURN</literal> rule with the parse tree
<emphasis>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
  FROM shoelace *OLD*, shoelace *NEW*,
       shoelace_data s, unit u
 WHERE bpchareq(s.sl_unit, u.un_name);</emphasis>
</ProgramListing>

    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
    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
SELECT shoelace.sl_name, shoelace.sl_avail,
       shoelace.sl_color, shoelace.sl_len,
       shoelace.sl_unit, shoelace.sl_len_cm
  FROM (SELECT s.sl_name,
               s.sl_avail,
               s.sl_color,
               s.sl_len,
               s.sl_unit,
               s.sl_len * u.un_fact AS sl_len_cm
          FROM shoelace_data s, unit u
         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
     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
     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
     the view, even though there's no direct use of the view in the rewritten
     query.
</Para>

<Para>
    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,
    so rewriting is complete and the above is the final result given to
    the planner.
</Para>

<Para>
    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.
</Para>

<Para>
    Al needs to know for which shoes currently in the store
    he has the matching shoelaces (color and size) 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
(2 rows)
</ProgramListing>

    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).
</Para>

<Para>
    The output of the parser this time is the parse 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);
    The first rule applied will be the one for the 
    <Filename>shoe_ready</Filename> view and it results in the
SELECT shoe_ready.shoename, shoe_ready.sh_avail,
       shoe_ready.sl_name, shoe_ready.sl_avail,
       shoe_ready.total_avail
  FROM (SELECT rsh.shoename,
               rsh.sh_avail,
               rsl.sl_name,
               rsl.sl_avail,
               min(rsh.sh_avail, rsl.sl_avail) AS total_avail
          FROM shoe rsh, shoelace rsl
         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);
</ProgramListing>

    Similarly, the rules for <Filename>shoe</Filename> and
    <Filename>shoelace</Filename> are substituted into the range table of
    the sub-query, leading to a three-level final query tree:
SELECT shoe_ready.shoename, shoe_ready.sh_avail,
       shoe_ready.sl_name, shoe_ready.sl_avail,
       shoe_ready.total_avail
  FROM (SELECT rsh.shoename,
               rsh.sh_avail,
               rsl.sl_name,
               rsl.sl_avail,
               min(rsh.sh_avail, rsl.sl_avail) AS total_avail
          FROM (SELECT sh.shoename,
                       sh.sh_avail,
                       sh.slcolor,
                       sh.slminlen,
                       sh.slminlen * un.un_fact AS slminlen_cm,
                       sh.slmaxlen,
                       sh.slmaxlen * un.un_fact AS slmaxlen_cm,
                       sh.slunit
                  FROM shoe_data sh, unit un
                 WHERE sh.slunit = un.un_name) rsh,
               (SELECT s.sl_name,
                       s.sl_avail,
                       s.sl_color,
                       s.sl_len,
                       s.sl_unit,
                       s.sl_len * u.un_fact AS sl_len_cm
                  FROM shoelace_data s, unit u
                 WHERE s.sl_unit = u.un_name) rsl
         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);
</ProgramListing>

    It turns out that the planner will collapse this tree into a two-level
    query tree: the bottommost selects will be <quote>pulled up</quote> 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>
    <Title>Note</Title>
    <Para>
    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 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 never happen if CREATE VIEW is used because
    for the first CREATE VIEW, the second relation does not exist
    and thus the first view cannot select from the second.
    </Para>
    </Note>
</Para>

</Sect2>

<Sect2>
<Title>View Rules in Non-SELECT Statements</Title>
    Two details of the parse 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
SELECT t2.b FROM t1, t2 WHERE t1.a = t2.a;
UPDATE t1 SET b = t2.b WHERE t1.a = t2.a;
</ProgramListing>

    are nearly identical.

    <ItemizedList>
        <ListItem>
	<Para>
	    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.
	</Para>
        </ListItem>

        <ListItem>
	<Para>
	    The qualification expressions compare the attributes a of both
	    ranges for equality.
	</Para>
        </ListItem>
	    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 as
UPDATE t1 SET a = t1.a, b = t2.b WHERE t1.a = t2.a;
</ProgramListing>

    and thus the executor run over the join will produce exactly the
    same result set as a

<ProgramListing>
SELECT t1.a, t2.b FROM t1, t2 WHERE t1.a = t2.a;
</ProgramListing>
    
    will do. But there is a little problem in 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 there
    has to be replaced by the new row?
    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 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 to the target list, the query actually looks like
SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a;
    Now another detail of <ProductName>PostgreSQL</ProductName> 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 xmax entries are set to the current
    command counter and current transaction ID. Thus the old row is hidden
    and after the transaction committed the vacuum cleaner can really move
    Knowing all that, we can simply apply view rules in absolutely
    the same way to any command. There is no difference.
</Para>
</Sect2>

<Sect2>
<Title>The Power of Views in <ProductName>PostgreSQL</ProductName></Title>

<Para>
    The above demonstrates how the rule system incorporates
    view definitions into the original parse 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 different names).
</Para>

<Sect3>
<Title>Benefits</Title>
    The benefit of implementing views with the rule system is,
    the information about which tables have to be scanned plus the
    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
    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, the better this decision can be. And
    the rule system as implemented in <ProductName>PostgreSQL</ProductName>
    ensures, that this is all information available about the query
    up to now.
</Para>
</Sect3>
</Sect2>

<Sect2 id="rules-views-update">
<Title>What about updating a view?</Title>
<indexterm zone="rules-views-update"><primary>views</><secondary>updating</></>
    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 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.
</Para>
</Sect2>

</Sect1>
<Title>Rules on INSERT, UPDATE and DELETE</Title>

<Sect2>
<Title>Differences from View Rules</Title>
    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:

    <ItemizedList>
        <ListItem>
	<Para>
	    They can have no action.
	</Para>
	</ListItem>

        <ListItem>
	<Para>
	    They can have multiple actions.
	</Para>
	</ListItem>

        <ListItem>
	<Para>
	    The keyword INSTEAD is optional.
	</Para>
	</ListItem>

        <ListItem>
	<Para>
	    The pseudo relations NEW and OLD become useful.
	</Para>
	</ListItem>

        <ListItem>
	<Para>
	    They can have rule qualifications.
	</Para>
	</ListItem>
    </ItemizedList>

    Second, they don't modify the parse tree in place. Instead they
    create zero or many new parse trees and can throw away the
<Sect2>
<Title>How These Rules Work</Title>
CREATE RULE rule_name AS ON event
    TO object [WHERE rule_qualification]
    DO [INSTEAD] [action | (actions) | NOTHING];
    In the following, <firstterm>update rules</> means rules that are defined
    Update rules get applied by the rule system when the result
    relation and the command type of a parse 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.
</Para>
    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
    special meaning).
    So we have four cases that produce the following parse trees for
<Para>
    <ItemizedList>
    <ListItem>
    <Para>
        No qualification and not INSTEAD:
        <ItemizedList>
	    <ListItem>
	    <Para>
	        The parse tree from the rule action where the
		original parse tree's qualification has been added.
	    </Para>
	    </ListItem>
	</ItemizedList>
    </Para>
    </ListItem>

    <ListItem>
    <Para>
        No qualification but INSTEAD:
        <ItemizedList>
	    <ListItem>
	    <Para>
	        The parse tree from the rule action where the
		original parse tree's qualification has been added.
	    </Para>
	    </ListItem>
	</ItemizedList>
    </Para>
    </ListItem>

    <ListItem>
    <Para>
        Qualification given and not INSTEAD:
        <ItemizedList>
	    <ListItem>
	    <Para>
	        The parse tree from the rule action where the rule
		qualification and the original parse tree's 
		qualification have been added.
	    </Para>
	    </ListItem>
	</ItemizedList>
    </Para>
    </ListItem>

    <ListItem>
    <Para>
        Qualification given and INSTEAD:
        <ItemizedList>
	    <ListItem>