Updatable Views
A view can be updatable or read-only.If a view is updatable, the data retrieved when this view is called can be changed by the DML statements INSERT, UPDATE, DELETE, UPDATE OR INSERT or MERGE.Changes made in an updatable view are applied to the underlying table(s).
A read-only view can be made updatable with the use of triggers.Once triggers have been defined on a view, changes posted to it will never be written automatically to the underlying table, even if the view was updatable to begin with.It is the responsibility of the programmer to ensure that the triggers update (or delete from, or insert into) the base tables as needed.
A view will be automatically updatable if all the following conditions are met:
-
the
SELECTstatement queries only one table or one updatable view -
the
SELECTstatement does not call any stored procedures -
each base table (or base view) column not present in the view definition meets one of the following conditions:
-
it is nullable
-
it has a non-
NULLdefault value -
it has a trigger that supplies a permitted value
-
-
the
SELECTstatement contains no fields derived from subqueries or other expressions -
the
SELECTstatement does not contain fields defined through aggregate functions (MIN,MAX,AVG,SUM,COUNT,LIST, etc.), statistical functions (CORR,COVAR_POP,COVAR_SAMP, etc.), linear regression functions (REGR_AVGX,REGR_AVGY, etc.) or any type of window function -
the
SELECTstatement contains noORDER BY,GROUP BYorHAVINGclause -
the
SELECTstatement does not include the keywordDISTINCTor row-restrictive keywords such asROWS,FIRST,SKIP,OFFSETorFETCH
|
Note
|
The RETURNING clause and updatable views
The To report the right values in |