Sophie

Sophie

distrib > Mandriva > current > i586 > media > main-updates > by-pkgid > fc62ce67f262cdcd253dc7f849ce3223 > files > 694

postgresql8.4-docs-8.4.12-0.1mdv2010.2.i586.rpm

<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN" "http://www.w3.org/TR/html4/loose.dtd">
<HTML
><HEAD
><TITLE
>Views and the Rule System</TITLE
><META
NAME="GENERATOR"
CONTENT="Modular DocBook HTML Stylesheet Version 1.79"><LINK
REV="MADE"
HREF="mailto:pgsql-docs@postgresql.org"><LINK
REL="HOME"
TITLE="PostgreSQL 8.4.12 Documentation"
HREF="index.html"><LINK
REL="UP"
TITLE="The Rule System"
HREF="rules.html"><LINK
REL="PREVIOUS"
TITLE="The Query Tree"
HREF="querytree.html"><LINK
REL="NEXT"
TITLE="Rules on INSERT, UPDATE, and DELETE"
HREF="rules-update.html"><LINK
REL="STYLESHEET"
TYPE="text/css"
HREF="stylesheet.css"><META
HTTP-EQUIV="Content-Type"
CONTENT="text/html; charset=ISO-8859-1"><META
NAME="creation"
CONTENT="2012-05-31T23:30:11"></HEAD
><BODY
CLASS="SECT1"
><DIV
CLASS="NAVHEADER"
><TABLE
SUMMARY="Header navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TH
COLSPAN="5"
ALIGN="center"
VALIGN="bottom"
>PostgreSQL 8.4.12 Documentation</TH
></TR
><TR
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="querytree.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="rules.html"
>Fast Backward</A
></TD
><TD
WIDTH="60%"
ALIGN="center"
VALIGN="bottom"
>Chapter 36. The Rule System</TD
><TD
WIDTH="10%"
ALIGN="right"
VALIGN="top"
><A
HREF="rules.html"
>Fast Forward</A
></TD
><TD
WIDTH="10%"
ALIGN="right"
VALIGN="top"
><A
HREF="rules-update.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
></TABLE
><HR
ALIGN="LEFT"
WIDTH="100%"></DIV
><DIV
CLASS="SECT1"
><H1
CLASS="SECT1"
><A
NAME="RULES-VIEWS"
>36.2. Views and the Rule System</A
></H1
><A
NAME="AEN46316"
></A
><A
NAME="AEN46319"
></A
><P
>    Views in <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> are implemented
    using the rule system. In fact, there is essentially no difference
    between:

</P><PRE
CLASS="PROGRAMLISTING"
>CREATE VIEW myview AS SELECT * FROM mytab;</PRE
><P>
    
    compared against the two commands:

</P><PRE
CLASS="PROGRAMLISTING"
>CREATE TABLE myview (<TT
CLASS="REPLACEABLE"
><I
>same column list as mytab</I
></TT
>);
CREATE RULE "_RETURN" AS ON SELECT TO myview DO INSTEAD
    SELECT * FROM mytab;</PRE
><P>
    
    because this is exactly what the <TT
CLASS="COMMAND"
>CREATE VIEW</TT
>
    command does internally.  This has some side effects. One of them
    is that the information about a view in the
    <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> system catalogs is exactly
    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.</P
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="RULES-SELECT"
>36.2.1. How <TT
CLASS="COMMAND"
>SELECT</TT
> Rules Work</A
></H2
><A
NAME="AEN46332"
></A
><P
>    Rules <TT
CLASS="LITERAL"
>ON SELECT</TT
> are applied to all queries as the last step, even
    if the command given is an <TT
CLASS="COMMAND"
>INSERT</TT
>,
    <TT
CLASS="COMMAND"
>UPDATE</TT
> or <TT
CLASS="COMMAND"
>DELETE</TT
>. And they
    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
    <TT
CLASS="COMMAND"
>SELECT</TT
> rules are described first.</P
><P
>    Currently, there can be only one action in an <TT
CLASS="LITERAL"
>ON SELECT</TT
> rule, and it must
    be an unconditional <TT
CLASS="COMMAND"
>SELECT</TT
> action that is <TT
CLASS="LITERAL"
>INSTEAD</TT
>. This restriction was
    required to make rules safe enough to open them for ordinary users, and
    it restricts <TT
CLASS="LITERAL"
>ON SELECT</TT
> rules to act like views.</P
><P
>    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
    <TT
CLASS="COMMAND"
>INSERT</TT
>, <TT
CLASS="COMMAND"
>UPDATE</TT
>, and
    <TT
CLASS="COMMAND"
>DELETE</TT
> operations so that the final result will
    be a view that behaves like a real table with some magic
    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.</P
><P
>For the example, we need a little <TT
CLASS="LITERAL"
>min</TT
> function that
returns the lower of 2 integer values. We create that as:

</P><PRE
CLASS="PROGRAMLISTING"
>CREATE FUNCTION min(integer, integer) RETURNS integer AS $$
    SELECT CASE WHEN $1 &lt; $2 THEN $1 ELSE $2 END
$$ LANGUAGE SQL STRICT;</PRE
><P></P
><P
>    The real tables we need in the first two rule system descriptions
    are these:

</P><PRE
CLASS="PROGRAMLISTING"
>CREATE TABLE shoe_data (
    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    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    text,          -- primary key
    un_fact    real           -- factor to transform to cm
);</PRE
><P>

    As you can see, they represent shoe-store data.</P
><P
>    The views are created as:

</P><PRE
CLASS="PROGRAMLISTING"
>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 &gt;= rsh.slminlen_cm
       AND rsl.sl_len_cm &lt;= rsh.slmaxlen_cm;</PRE
><P>

    The <TT
CLASS="COMMAND"
>CREATE VIEW</TT
> command for the
    <TT
CLASS="LITERAL"
>shoelace</TT
> view (which is the simplest one we
    have) will create a relation <TT
CLASS="LITERAL"
>shoelace</TT
> and an entry in
    <TT
CLASS="STRUCTNAME"
>pg_rewrite</TT
> that tells that there is a
    rewrite rule that must be applied whenever the relation <TT
CLASS="LITERAL"
>shoelace</TT
>
    is referenced in a query's range table.  The rule has no rule
    qualification (discussed later, with the non-<TT
CLASS="COMMAND"
>SELECT</TT
> rules, since
    <TT
CLASS="COMMAND"
>SELECT</TT
> rules currently cannot have them) and it is <TT
CLASS="LITERAL"
>INSTEAD</TT
>. 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
    <TT
CLASS="COMMAND"
>SELECT</TT
> statement in the view creation command.</P
><DIV
CLASS="NOTE"
><BLOCKQUOTE
CLASS="NOTE"
><P
><B
>Note: </B
>    The two extra range
    table entries for <TT
CLASS="LITERAL"
>NEW</TT
> and <TT
CLASS="LITERAL"
>OLD</TT
> (named <TT
CLASS="LITERAL"
>*NEW*</TT
> and <TT
CLASS="LITERAL"
>*OLD*</TT
> for
    historical reasons in the printed query tree) you can see in
    the <TT
CLASS="STRUCTNAME"
>pg_rewrite</TT
> entry aren't of interest
    for <TT
CLASS="COMMAND"
>SELECT</TT
> rules.
    </P
></BLOCKQUOTE
></DIV
><P
>    Now we populate <TT
CLASS="LITERAL"
>unit</TT
>, <TT
CLASS="LITERAL"
>shoe_data</TT
>
    and <TT
CLASS="LITERAL"
>shoelace_data</TT
> and run a simple query on a view:

</P><PRE
CLASS="PROGRAMLISTING"
>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)</PRE
><P>
   </P
><P
>    This is the simplest <TT
CLASS="COMMAND"
>SELECT</TT
> you can do on our
    views, so we take this opportunity to explain the basics of view
    rules.  The <TT
CLASS="LITERAL"
>SELECT * FROM shoelace</TT
> was
    interpreted by the parser and produced the query tree:

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT shoelace.sl_name, shoelace.sl_avail,
       shoelace.sl_color, shoelace.sl_len,
       shoelace.sl_unit, shoelace.sl_len_cm
  FROM shoelace shoelace;</PRE
><P>

    and this is given to the rule system. The rule system walks through the
    range table and checks if there are rules
    for any relation. When processing the range table entry for
    <TT
CLASS="LITERAL"
>shoelace</TT
> (the only one up to now) it finds the
    <TT
CLASS="LITERAL"
>_RETURN</TT
> rule with the query tree:

</P><PRE
CLASS="PROGRAMLISTING"
>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 *OLD*, shoelace *NEW*,
       shoelace_data s, unit u
 WHERE s.sl_unit = u.un_name;</PRE
><P></P
><P
>    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 query tree is almost the same as if you had typed:

</P><PRE
CLASS="PROGRAMLISTING"
>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;</PRE
><P>

     There is one difference however: the subquery's range table has two
     extra entries <TT
CLASS="LITERAL"
>shoelace *OLD*</TT
> and <TT
CLASS="LITERAL"
>shoelace *NEW*</TT
>.  These entries don't
     participate directly in the query, since they aren't referenced by
     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 privileges to access
     the view, even though there's no direct use of the view in the rewritten
     query.</P
><P
>    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 subquery to see if any of them reference views.  (But it
    won't expand <TT
CLASS="LITERAL"
>*OLD*</TT
> or <TT
CLASS="LITERAL"
>*NEW*</TT
> &mdash; otherwise we'd have infinite recursion!)
    In this example, there are no rewrite rules for <TT
CLASS="LITERAL"
>shoelace_data</TT
> or <TT
CLASS="LITERAL"
>unit</TT
>,
    so rewriting is complete and the above is the final result given to
    the planner.</P
><P
>    Now 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.

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT * FROM shoe_ready WHERE total_avail &gt;= 2;

 shoename | sh_avail | sl_name | sl_avail | total_avail
----------+----------+---------+----------+-------------
 sh1      |        2 | sl1     |        5 |           2
 sh3      |        4 | sl7     |        7 |           4
(2 rows)</PRE
><P></P
><P
>    The output of the parser this time is the query tree:

</P><PRE
CLASS="PROGRAMLISTING"
>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 shoe_ready.total_avail &gt;= 2;</PRE
><P>

    The first rule applied will be the one for the 
    <TT
CLASS="LITERAL"
>shoe_ready</TT
> view and it results in the
    query tree:

</P><PRE
CLASS="PROGRAMLISTING"
>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 &gt;= rsh.slminlen_cm
           AND rsl.sl_len_cm &lt;= rsh.slmaxlen_cm) shoe_ready
 WHERE shoe_ready.total_avail &gt;= 2;</PRE
><P>

    Similarly, the rules for <TT
CLASS="LITERAL"
>shoe</TT
> and
    <TT
CLASS="LITERAL"
>shoelace</TT
> are substituted into the range table of
    the subquery, leading to a three-level final query tree:

</P><PRE
CLASS="PROGRAMLISTING"
>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 &gt;= rsh.slminlen_cm
           AND rsl.sl_len_cm &lt;= rsh.slmaxlen_cm) shoe_ready
 WHERE shoe_ready.total_avail &gt; 2;</PRE
><P>
   </P
><P
>    It turns out that the planner will collapse this tree into a
    two-level query tree: the bottommost <TT
CLASS="COMMAND"
>SELECT</TT
>
    commands will be <SPAN
CLASS="QUOTE"
>"pulled up"</SPAN
> into the middle
    <TT
CLASS="COMMAND"
>SELECT</TT
> since there's no need to process them
    separately.  But the middle <TT
CLASS="COMMAND"
>SELECT</TT
> will remain
    separate from the top, because it contains aggregate functions.
    If we pulled those up it would change the behavior of the topmost
    <TT
CLASS="COMMAND"
>SELECT</TT
>, which we don't want.  However,
    collapsing the query tree is an optimization that the rewrite
    system doesn't have to concern itself with.
   </P
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="AEN46410"
>36.2.2. View Rules in Non-<TT
CLASS="COMMAND"
>SELECT</TT
> Statements</A
></H2
><P
>    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.</P
><P
>    There are only a few differences between a query tree for a
    <TT
CLASS="COMMAND"
>SELECT</TT
> and one for any other
    command. Obviously, they have a different command type and for a
    command other than a <TT
CLASS="COMMAND"
>SELECT</TT
>, the result
    relation points to the range-table entry where the result should
    go.  Everything else is absolutely the same.  So having two tables
    <TT
CLASS="LITERAL"
>t1</TT
> and <TT
CLASS="LITERAL"
>t2</TT
> with columns <TT
CLASS="LITERAL"
>a</TT
> and
    <TT
CLASS="LITERAL"
>b</TT
>, the query trees for the two statements:

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT t2.b FROM t1, t2 WHERE t1.a = t2.a;

UPDATE t1 SET b = t2.b FROM t2 WHERE t1.a = t2.a;</PRE
><P>

    are nearly identical.  In particular:

    <P
></P
></P><UL
><LI
><P
>            The range tables contain entries for the tables <TT
CLASS="LITERAL"
>t1</TT
> and <TT
CLASS="LITERAL"
>t2</TT
>.
        </P
></LI
><LI
><P
>            The target lists contain one variable that points to column
            <TT
CLASS="LITERAL"
>b</TT
> of the range table entry for table <TT
CLASS="LITERAL"
>t2</TT
>.
        </P
></LI
><LI
><P
>            The qualification expressions compare the columns <TT
CLASS="LITERAL"
>a</TT
> of both
            range-table entries for equality.
        </P
></LI
><LI
><P
>            The join trees show a simple join between <TT
CLASS="LITERAL"
>t1</TT
> and <TT
CLASS="LITERAL"
>t2</TT
>.
        </P
></LI
></UL
><P>
   </P
><P
>    The consequence is, that both query trees result in similar
    execution plans: They are both joins over the two tables. For the
    <TT
CLASS="COMMAND"
>UPDATE</TT
> the missing columns from <TT
CLASS="LITERAL"
>t1</TT
> are added to
    the target list by the planner and the final query tree will read
    as:

</P><PRE
CLASS="PROGRAMLISTING"
>UPDATE t1 SET a = t1.a, b = t2.b FROM t2 WHERE t1.a = t2.a;</PRE
><P>

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

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT t1.a, t2.b FROM t1, t2 WHERE t1.a = t2.a;</PRE
><P>
    
    will do. But there is a little problem in
    <TT
CLASS="COMMAND"
>UPDATE</TT
>: 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
    <TT
CLASS="COMMAND"
>SELECT</TT
> command and the other is an
    <TT
CLASS="COMMAND"
>UPDATE</TT
> is handled in the caller of the
    executor. The caller still knows (looking at the query tree) that
    this is an <TT
CLASS="COMMAND"
>UPDATE</TT
>, and it knows that this
    result should go into table <TT
CLASS="LITERAL"
>t1</TT
>. But which of the rows that are
    there has to be replaced by the new row?</P
><P
>    To resolve this problem, another entry is added to the target list
    in <TT
CLASS="COMMAND"
>UPDATE</TT
> (and also in
    <TT
CLASS="COMMAND"
>DELETE</TT
>) statements: the current tuple ID
    (<ACRONYM
CLASS="ACRONYM"
>CTID</ACRONYM
>).<A
NAME="AEN46452"
></A
>
    This is a system column containing the
    file block number and position in the block for the row. Knowing
    the table, the <ACRONYM
CLASS="ACRONYM"
>CTID</ACRONYM
> can be used to retrieve the
    original row of <TT
CLASS="LITERAL"
>t1</TT
> to be updated.  After adding the
    <ACRONYM
CLASS="ACRONYM"
>CTID</ACRONYM
> to the target list, the query actually looks like:

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a;</PRE
><P>
    
    Now another detail of <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> enters
    the stage. Old table rows aren't overwritten, and this
    is why <TT
CLASS="COMMAND"
>ROLLBACK</TT
> is fast. In an <TT
CLASS="COMMAND"
>UPDATE</TT
>,
    the new result row is inserted into the table (after stripping the
    <ACRONYM
CLASS="ACRONYM"
>CTID</ACRONYM
>) and in the row header of the old row, which the
    <ACRONYM
CLASS="ACRONYM"
>CTID</ACRONYM
> pointed to, the <TT
CLASS="LITERAL"
>cmax</TT
> and
    <TT
CLASS="LITERAL"
>xmax</TT
> entries are set to the current command counter
    and current transaction ID. Thus the old row is hidden, and after
    the transaction commits the vacuum cleaner can really remove it.</P
><P
>    Knowing all that, we can simply apply view rules in absolutely
    the same way to any command. There is no difference.</P
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="AEN46466"
>36.2.3. The Power of Views in <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
></A
></H2
><P
>    The above demonstrates how the rule system incorporates view
    definitions into the original query tree. In the second example, a
    simple <TT
CLASS="COMMAND"
>SELECT</TT
> from one view created a final
    query tree that is a join of 4 tables (<TT
CLASS="LITERAL"
>unit</TT
> was used twice with
    different names).</P
><P
>    The benefit of implementing views with the rule system is,
    that the planner has all
    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 query tree. And this is still the situation
    when the original query is already a join over views.
    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 <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
>
    ensures, that this is all information available about the query
    up to that point.</P
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="RULES-VIEWS-UPDATE"
>36.2.4. Updating a View</A
></H2
><P
>    What happens if a view is named as the target relation for an
    <TT
CLASS="COMMAND"
>INSERT</TT
>, <TT
CLASS="COMMAND"
>UPDATE</TT
>, or
    <TT
CLASS="COMMAND"
>DELETE</TT
>?  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.</P
><P
>    To change this, we can define rules that modify the behavior of
    these kinds of commands. This is the topic of the next section.</P
></DIV
></DIV
><DIV
CLASS="NAVFOOTER"
><HR
ALIGN="LEFT"
WIDTH="100%"><TABLE
SUMMARY="Footer navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
><A
HREF="querytree.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="index.html"
ACCESSKEY="H"
>Home</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
><A
HREF="rules-update.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
>The Query Tree</TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="rules.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
>Rules on <TT
CLASS="COMMAND"
>INSERT</TT
>, <TT
CLASS="COMMAND"
>UPDATE</TT
>, and <TT
CLASS="COMMAND"
>DELETE</TT
></TD
></TR
></TABLE
></DIV
></BODY
></HTML
>