This topic describes how to create, modify, and drop views. A view displays the result of a query. You can use views in most cases where you can use tables. If the data you frequently access is distributed across multiple tables, a view is the best choice.
Create a normal view
You can execute the CREATE VIEW statement to create a normal view. After a view is created, you can execute DML statements on it.
Syntax for creating a view in MySQL mode:
create_view_stmt:
CREATE [OR REPLACE] VIEW view_name [(column_name_list)] AS select_stmt;
[WITH [CASCADED | LOCAL] CHECK OPTION];
column_name_list:
column_name [, column_name ...]
Parameters:
OR REPLACE: If the name of the view to be created already exists, a new view is created based on the specified definition.select_stmt: defines theSELECTstatement of the view. You can obtain the information to be used in this statement from a base table or other views.column_name_list: the unique column names used in the view. Each base table must also have unique column names. By default, the column names retrieved by theSELECTstatement are used as the column names in the view.You can also use the optional
column_name_listclause to define column names for a view. Separate multiple column names with commas (,). The number of column names incolumn_name_listmust be equal to the number of columns retrieved by theSELECTstatement.The
SELECTstatement can directly reference the columns of a table. You can also use functions, constants, and operators in the statement to retrieve columns.The
WITH CHECK OPTIONclause prevents the system from inserting or updating rows except for the rows that meet the query condition defined by theWHEREclause inselect_statement. When you create a view by using theWITH CHECK OPTIONclause, you can add theCASCADEDorLOCALkeyword to clarify the check scope.If the
LOCALkeyword is used, theWHEREclause of a view is checked, then checking recurses to underlying views and applies the same rules.If the
CASCADEDkeyword is used, theWHEREclause of a view is checked, then checking recurses to underlying views, addsWITH CASCADED CHECK OPTIONto these views without changing their definitions, and applies the same rules.If neither the
CASCADEDnor theLOCALkeyword is used inWITH CHECK OPTION, theCASCADEDkeyword takes effect by default.If the
WITH CHECK OPTIONclause is not used when you create a view, theWHEREclause of this view is not checked, then checking recurses to underlying views and applies the same rules.
Example:
obclient> CREATE VIEW stock_item
AS
SELECT /*+ leading(s) use_merge(i) */
i_price, i_name, i_data, s_i_id, s_w_id, s_order_cnt, s_ytd, s_remote_cnt, s_quantity, s_data, s_dist_01, s_dist_02, s_dist_03, s_dist_04, s_dist_05, s_dist_06, s_dist_07, s_dist_08, s_dist_09, s_dist_10
FROM stok s, item i
WHERE s.s_i_id = i.i_id;
Query OK, 0 rows affected
Create a read-only view
You can add the WITH READ ONLY keyword to the CREATE OR REPLACE VIEW statement to create a read-only view. You cannot execute any DML statements on a read-only view, including INSERT, UPDATE, DELETE, and REPLACE.
Example: Create a read-only view named view1.
obclient> CREATE OR REPLACE VIEW view1 AS SELECT * FROM tab1 WITH READ ONLY;
Modify a normal view
You can execute the CREATE OR REPLACE VIEW statement to modify a normal view.
Example: Modify the stock_item view.
obclient> CREATE OR REPLACE VIEW stock_item
AS
SELECT /*+ leading(s) use_merge(i) */
i_price, i_name, i_data, s_i_id, s_w_id, s_order_cnt, s_ytd, s_remote_cnt, s_quantity, s_data, s_dist_01, s_dist_02, s_dist_03, s_dist_04, s_dist_05, s_dist_06, s_dist_07, s_dist_08, s_dist_09, s_dist_10
FROM stok s, item i
WHERE s.s_i_id = i.i_id;
Query OK, 0 rows affected (0.02 sec)
Drop a view
You can execute the DROP VIEW statement to drop one or more views at a time. When a view is dropped, tables referenced by the view are not dropped.
If you drop a view that is referenced by another view, queries on the view that references the dropped view will fail.
Before you drop a view, make sure that you have the DROP privilege on the view.
Syntax for dropping a view in MySQL mode:
drop_view_stmt:
DROP VIEW [IF EXISTS] view_name_list;
view_name_list:
view_name [, view_name_list]
Note:
The
IF EXISTSkeyword prevents the error that occurs because the view to be dropped does not exist.If
view_name_listcontains views that do not exist, an error may be reported during execution but the specified views that exist are dropped.
Example: Drop the V1 view.
obclient> DROP VIEW V1;