View materialization implementation

The view materialization implementation runs the query of the view and places the results in a temporary result. The view reference in the user's query is then replaced with the temporary, and the query is run against the temporary result.

Start of changeView materialization is done whenever it is not possible to create a view composite. Note that for SQE, view materialization is optional. The following types of queries require view materialization:End of change

Start of changeEnd of change

When a temporary result table is created, access methods that are allowed with ALWCPYDTA(*OPTIMIZE) may be used to implement the query. These methods include hash grouping, hash join, and bitmaps.

See the following examples:

CREATE VIEW AVGSALVW AS
  SELECT WORKDEPT, AVG(SALARY) AS AVGSAL
  FROM CORPDATA.EMPLOYEE
  GROUP BY WORKDEPT

SQL example:

  SELECT D.DEPTNAME, A.AVGSAL
  FROM CORPDATA.DEPARTMENT D, AVGSALVW A
  WHERE D.DEPTNO=A.WORKDEPT

In this case, a view composite cannot be created since a join query references a grouping view. The results of AVGSALVW are placed in a temporary result table (*QUERY0001). The view reference AVGSALVW is replaced with the temporary result table. The new query is then run. The generated query looks like the following:

SELECT D.DEPTNAME, A.AVGSAL
  FROM CORPDATA.DEPARTMENT D, *QUERY0001 A
  WHERE D.DEPTNO=A.WORKDEPT
Note: The new query that the query optimizer generates is not visible to users. Only the original query against the view will be seen by users and database performance tools.

Whenever possible, isolatable selection from the query, except subquery predicates, is added to the view materialization process. This results in smaller temporary result tables and allows existing indexes to be used when materializing the view. This will not be done if there is more than one reference to the same view or common table expression in the query. The following is an example where isolatable selection is added to the view materialization:

SELECT D.DEPTNAME,A.AVGSAL 	
  FROM CORPDATA.DEPARTMENT D, AVGSALVW A
  WHERE D.DEPTNO=A.WORKDEPT AND
  A.WORKDEPT LIKE 'D%' AND AVGSAL>10000

The isolatable selection from the query is added to the view resulting in a new query to generate the temporary result table:

SELECT WORKDEPT, AVG(SALARY) AS AVGSAL
  FROM CORPDATA.EMPLOYEE
  WHERE WORKDEPT LIKE 'D%'
  GROUP BY WORKDEPT
  HAVING AVG(SALARY)>10000