The CREATE VIEW statement creates a view on one or more tables or views at the current server.
This statement can be embedded in an application program or issued interactively. It is an executable statement that can be dynamically prepared.
The privileges held by the authorization ID of the statement must include at least one of the following:
The privileges held by the authorization ID of the statement must include at least one of the following:
The privileges held by the authorization ID of the statement must also include at least one of the following:
For information on the system authorities corresponding to SQL privileges, see Corresponding System Authorities When Checking Privileges to a Table or View and Corresponding System Authorities When Checking Privileges to a Distinct Type.
>>-CREATE VIEW--+-----------+--VIEW--view-name------------------> '-RECURSIVE-' >--+----------------------------------------------------------------+--> | .-,----------------------------------------------------. | | V | | '-(----column-name--+-------------------------------------+-+--)-' | .-COLUMN-. | '-FOR--+--------+--system-column-name-' >--AS--+-----------------------------------+--fullselect--------> | .-,-----------------------. | | V | | '-WITH----common-table-expression-+-' >--+----------------------------------+------------------------>< | .-CASCADED-. | '-WITH--+----------+--CHECK OPTION-' '-LOCAL----'
If a fullselect of the view contains a reference to the view itself in a FROM clause, the view is a recursive view. Views using recursion are useful in supporting applications such as bill of materials (BOM), reservation systems, and network planning.
The restrictions that apply to a recursive view are similar to those for a recursive common table expression:
If a column name of the view is referred to in the iterative fullselect, the attributes of the result columns are determined using the rules for result columns. For more information see Rules for result data types.
Recursive views are not allowed if the query specifies:
If SQL names were specified, the view will be created in the schema specified by the implicit or explicit qualifier.
If system names were specified, the view will be created in the schema that is specified by the qualifier. If not qualified, the view name will be created in the same schema as the first table specified on the first FROM clause (including FROM clauses in any common table expressions or nested table expression).
If a view name is not a valid system name, DB2 UDB for iSeries SQL will generate a system name. For information on the rules for generating the name, see Rules for Table Name Generation.
A list of column names (and system column names) must be specified if the result table of the subselect has duplicate column names, duplicate system column names, or an unnamed column. For more information about unnamed columns, see Names of result columns.
If the system-column-name is not specified, and the column-name is not a valid system-column-name, a system column name is generated. For more information about how system column names are generated, see Rules for Column Name Generation.
fullselect must not reference variables.
The maximum number of columns allowed in a view is 8000. The column name lengths and the length of the WHERE clause also reduce this number. The maximum number of base tables allowed in the view is 256.
For an explanation of fullselect, see fullselect.
common-table-expression defines a common table expression for use with the fullselect that follows. For more information see common-table-expression.
CHECK OPTION must not be specified if:
If CHECK OPTION is specified for an updatable view that does not allow inserts, then the check option applies to updates only.
If CHECK OPTION is omitted, the definition of the view is not used in the checking of any insert or update operations that use the view. Some checking might still occur during insert or update operations if the view is directly or indirectly dependent on another view that includes a CHECK OPTION. Because the definition of the view is not used, rows that do not conform to the definition of the view might be inserted or updated through the view.
CREATE VIEW V1 AS SELECT COL1 FROM T1 WHERE COL1 > 10 CREATE VIEW V2 AS SELECT COL1 FROM V1 WITH CHECK OPTION CREATE VIEW V3 AS SELECT COL1 FROM V2 WHERE COL1 < 100
SQL statement | Description of result |
---|---|
INSERT INTO V1 VALUES(5) | Succeeds because V1 does not have a CHECK OPTION clause and it is not dependent on any other view that has a CHECK OPTION clause. |
INSERT INTO V2 VALUES(5) | Results in an error because the inserted row does not conform to the search condition of V1 which is implicitly part of the definition of V2. |
INSERT INTO V3 VALUES(5) | Results in an error because V3 is dependent on V2 which has a CHECK OPTION clause and the inserted row does not conform to the definition of V2. |
INSERT INTO V3 VALUES(200) | Succeeds even though it does not conform to the definition of V3 (V3 does not have the view CHECK OPTION clause specified); it does conform to the definition of V2 (which does have the view CHECK OPTION clause specified). |
WITH LOCAL CHECK OPTION specifies that the search conditions of the following underlying views are checked when a row is inserted or updated:
In contrast, WITH CASCADED CHECK OPTION specifies that the search conditions of all underlying views are checked when a row is inserted or updated.
The difference between CASCADED and LOCAL is best shown by example. Consider the following updatable views where x and y represent either LOCAL or CASCADED:
V1 defined on table T0 V2 defined on V1 WITH x CHECK OPTION V3 defined on V2 V4 defined on V3 WITH y CHECK OPTION V5 defined on V4
The following table describes which views search conditions are checked during an INSERT or UPDATE operation:
View used in INSERT or UPDATE | x = LOCAL
y = LOCAL |
x = CASCADED
y = CASCADED |
x = LOCAL
y = CASCADED |
x = CASCADED
y = LOCAL |
---|---|---|---|---|
V1 | none | none | none | none |
V2 | V2 | V2 V1 | V2 | V2 V1 |
V3 | V2 | V2 V1 | V2 | V2 V1 |
V4 | V4 V2 | V4 V3 V2 V1 | V4 V3 V2 V1 | V4 V2 V1 |
V5 | V4 V2 | V4 V3 V2 V1 | V4 V3 V2 V1 | V4 V2 V1 |
View ownership: If SQL names were specified:
If system names were specified, the owner of the view is the user profile or group user profile of the job executing the statement.
View authority: If SQL names are used, views are created with the system authority of *EXCLUDE on *PUBLIC. If system names are used, views are created with the authority to *PUBLIC as determined by the create authority (CRTAUT) parameter of the schema.
If the owner of the view is a member of a group profile (GRPPRF keyword) and group authority is specified (GRPAUT keyword), that group profile will also have authority to the view.
The owner always acquires the SELECT privilege on the view and the authorization to drop the view. The SELECT privilege can be granted to others only if the owner also has the authority to grant the SELECT privilege on every table or view identified in the fullselect.
The owner can also acquire the INSERT, UPDATE, and DELETE privileges on the view. If the view is not read-only, then the same privileges will be acquired on the new view as the owner has on the table or view identified in the first FROM clause of the fullselect. These privileges can be granted only if the privileges from which they are derived can also be granted.
Deletable views: A view is deletable if an INSTEAD OF trigger for the delete operation has been defined for the view, or if all of the following are true:
Updatable views: A view is updatable if an INSTEAD OF trigger for the update operation has been defined for the view, or if all of the following are true:
A column of a view is updatable if an INSTEAD OF trigger for the update operation has been defined for the view, or if the corresponding result column of the subselect is derived solely from a column of a table or an updatable column of another view (that is, it is not derived from an expression that contains an operator, scalar function, constant, or a column that itself is derived from such expressions).
Insertable views: A view is insertable if an INSTEAD OF trigger for the insert operation has been defined for the view, or if at least one column of the view is updatable (independent of an INSTEAD OF trigger for update).
Read-only views: A view is read-only if it is not deletable.
A read-only view cannot be the object of an INSERT, UPDATE, or DELETE statement.
Unqualified table names: If the CREATE VIEW statement refers to an unqualified table name, the following rules are applied to determine which table is actually being referenced:
Sort sequence: The view is created with the sort sequence in effect at the time the CREATE VIEW statement is executed. The sort sequence of the view applies to all comparisons involving SBCS data and mixed data in the view fullselect. When the view is included in a query, an intermediate result table is generated from the view fullselect. The sort sequence in effect when the query is executed applies to any selection specified in the query.
View attributes: Views are created as nonkeyed logical files. When a view is created, the file wait time and record wait time attributes are set to the default that is specified on the WAITFILE and WAITRCD keywords of the Create Logical File (CRTLF) command.
The date and time format used for date and time result columns is ISO.
A view created over a distributed table is created on all of the systems across which the table is distributed. If a view is created over more than one distributed table, and those tables are not distributed using the same nodegroup, then the view is created only on the system that performs the CREATE VIEW statement. For more information about distributed tables, see the DB2® Multisystem book.
Identity columns: A column of a view is considered an identity column if the element of the corresponding column in the fullselect of the view definition is the name of an identity column of a table, or the name of a column of a view which directly or indirectly maps to the name of an identity column of a base table. In all other cases, the columns of a view will not get the identity property. For example:
Example 1: Create a view named MA_PROJ over the PROJECT table that contains only those rows with a project number (PROJNO) starting with the letters 'MA'.
CREATE VIEW MA_PROJ AS SELECT * FROM PROJECT WHERE SUBSTR(PROJNO, 1, 2) = 'MA'
Example 2: Create a view as in example 1, but select only the columns for project number (PROJNO), project name (PROJNAME) and employee in charge of the project (RESPEMP).
CREATE VIEW MA_PROJ2 AS SELECT PROJNO, PROJNAME, RESPEMP FROM PROJECT WHERE SUBSTR(PROJNO, 1, 2) = 'MA'
Example 3: Create a view as in example 2, but, in the view, call the column for the employee in charge of the project IN_CHARGE.
CREATE VIEW MA_PROJ (PROJNO, PROJNAME, IN_CHARGE) AS SELECT PROJNO, PROJNAME, RESPEMP FROM PROJECT WHERE SUBSTR(PROJNO, 1, 2) = 'MA'
Example 4: Create a view named PRJ_LEADER that contains the first four columns (PROJNO, PROJNAME, DEPTNO, RESPEMP) from the PROJECT table together with the last name (LASTNAME) of the person who is responsible for the project (RESPEMP). Obtain the name from the EMPLOYEE table by matching EMPNO in EMPLOYEE to RESEMP in PROJECT.
CREATE VIEW PRJ_LEADER AS SELECT PROJNO, PROJNAME, DEPTNO, RESPEMP, LASTNAME FROM PROJECT, EMPLOYEE WHERE RESPEMP = EMPNO
Example 5: Create a view as in example 4, but in addition to the columns PROJNO, PROJNAME, DEPTNO, RESEMP and LASTNAME, show the total pay (SALARY + BONUS +COMM) of the employee who is responsible. Also select only those projects with mean staffing (PRSTAFF) greater than one.
CREATE VIEW PRJ_LEADER (PROJNO, PROJNAME, DEPTNO, RESPEMP, LASTNAME, TOTAL_PAY) AS SELECT PROJNO, PROJNAME, DEPTNO, RESPEMP, LASTNAME, SALARY+BONUS+COMM FROM PROJECT, EMPLOYEE WHERE RESPEMP = EMPNO AND PRSTAFF > 1
Example 6: Create a recursive view that returns a similar result as a common table expression, see Single level explosion.
CREATE RECURSIVE VIEW RPL (PART, SUBPART, QUANTITY) AS SELECT ROOT.PART, ROOT.SUBPART, ROOT.QUANTITY FROM PARTLIST ROOT WHERE ROOT.PART = '01' UNION ALL SELECT CHILD.PART, CHILD.SUBPART, CHILD.QUANTITY FROM RPL PARENT, PARTLIST CHILD WHERE PARENT.SUBPART = CHILD.PART SELECT DISTINCT * FROMRPL ORDER BY PART, SUBPART, QUANTITY