Some views are updatable. That is, you can use them in statements
such as UPDATE
,
DELETE
, or
INSERT
to update the contents of
the underlying table. For a view to be updatable, there must be a
one-to-one relationship between the rows in the view and the rows
in the underlying table. There are also certain other constructs
that make a view nonupdatable. To be more specific, a view is not
updatable if it contains any of the following:
Aggregate functions (SUM()
,
MIN()
,
MAX()
,
COUNT()
, and so forth)
DISTINCT
GROUP BY
HAVING
Subquery in the select list
Certain joins (see additional join discussion later in this section)
Nonupdatable view in the FROM
clause
A subquery in the WHERE
clause that refers
to a table in the FROM
clause
Refers only to literal values (in this case, there is no underlying table to update)
Uses ALGORITHM = TEMPTABLE
(use of a
temporary table always makes a view nonupdatable)
Multiple references to any column of a base table.
With respect to insertability (being updatable with
INSERT
statements), an updatable
view is insertable if it also satisfies these additional
requirements for the view columns:
There must be no duplicate view column names.
The view must contain all columns in the base table that do not have a default value.
The view columns must be simple column references and not derived columns. A derived column is one that is not a simple column reference but is derived from an expression. These are examples of derived columns:
3.14159
col1 + 3
UPPER(col2)
col3 / col4
(subquery
)
A view that has a mix of simple column references and derived columns is not insertable, but it can be updatable if you update only those columns that are not derived. Consider this view:
CREATE VIEW v AS SELECT col1, 1 AS col2 FROM t;
This view is not insertable because col2
is
derived from an expression. But it is updatable if the update does
not try to update col2
. This update is
allowable:
UPDATE v SET col1 = 0;
This update is not allowable because it attempts to update a derived column:
UPDATE v SET col2 = 0;
It is sometimes possible for a multiple-table view to be
updatable, assuming that it can be processed with the
MERGE
algorithm. For this to work, the view
must use an inner join (not an outer join or a
UNION
). Also, only a single table
in the view definition can be updated, so the
SET
clause must name only columns from one of
the tables in the view. Views that use
UNION ALL
are
disallowed even though they might be theoretically updatable,
because the implementation uses temporary tables to process them.
For a multiple-table updatable view,
INSERT
can work if it inserts into
a single table. DELETE
is not
supported.
INSERT DELAYED
is not supported for
views.
If a table contains an AUTO_INCREMENT
column,
inserting into an insertable view on the table that does not
include the AUTO_INCREMENT
column does not
change the value of
LAST_INSERT_ID()
, because the side
effects of inserting default values into columns not part of the
view should not be visible.
The WITH CHECK OPTION
clause can be given for
an updatable view to prevent inserts or updates to rows except
those for which the WHERE
clause in the
select_statement
is true.
In a WITH CHECK OPTION
clause for an updatable
view, the LOCAL
and CASCADED
keywords determine the scope of check testing when the view is
defined in terms of another view. The LOCAL
keyword restricts the CHECK OPTION
only to the
view being defined. CASCADED
causes the checks
for underlying views to be evaluated as well. When neither keyword
is given, the default is CASCADED
. Consider the
definitions for the following table and set of views:
mysql>CREATE TABLE t1 (a INT);
mysql>CREATE VIEW v1 AS SELECT * FROM t1 WHERE a < 2
->WITH CHECK OPTION;
mysql>CREATE VIEW v2 AS SELECT * FROM v1 WHERE a > 0
->WITH LOCAL CHECK OPTION;
mysql>CREATE VIEW v3 AS SELECT * FROM v1 WHERE a > 0
->WITH CASCADED CHECK OPTION;
Here the v2
and v3
views are
defined in terms of another view, v1
.
v2
has a LOCAL
check option,
so inserts are tested only against the v2
check. v3
has a CASCADED
check option, so inserts are tested not only against its own
check, but against those of underlying views. The following
statements illustrate these differences:
mysql>INSERT INTO v2 VALUES (2);
Query OK, 1 row affected (0.00 sec) mysql>INSERT INTO v3 VALUES (2);
ERROR 1369 (HY000): CHECK OPTION failed 'test.v3'
MySQL sets a flag, called the view updatability flag, at
CREATE VIEW
time. The flag is set
to YES
(true) if
UPDATE
and
DELETE
(and similar operations) are
legal for the view. Otherwise, the flag is set to
NO
(false). The IS_UPDATABLE
column in the
INFORMATION_SCHEMA.VIEWS
table
displays the status of this flag. It means that the server always
knows whether a view is updatable. If the view is not updatable,
statements such UPDATE
,
DELETE
, and
INSERT
are illegal and will be
rejected. (Note that even if a view is updatable, it might not be
possible to insert into it, as described elsewhere in this
section.)
The updatability of views may be affected by the value of the
updatable_views_with_limit
system
variable. See Section 5.1.3, “Server System Variables”.
User Comments
One of the limitations above is that you cannot have duplicate column names. This does not make sense as you already cannot have duplicate column names. What I think they are trying to convey is this:
You cannot have duplicate base columns in the view for it to be insertable.
Example:
mysql> use world
Database changed
mysql> CREATE TABLE `city1` (
`ID` int(11) NOT NULL AUTO_INCREMENT,
`Name` char(35) NOT NULL DEFAULT '',
PRIMARY KEY (`ID`)
) ENGINE=MyISAM
Query OK, 0 rows affected (0.03 sec)
mysql> create view city_v1 as select ID as ID1, ID as ID2, Name from city;
Query OK, 0 rows affected (0.03 sec)
mysql> insert into city_v1 (ID1,Name) VALUES (10000,'Blah');
ERROR 1471 (HY000): The target table city_v1 of the INSERT is not insertable-into
Add your own comment.