2.2. Create Materialized Views


You can create materialized views and their corresponding physical materialized target tables in the Teiid Designer JBDS plug-in. This can be done through setting the materialized and target table manually, or by selecting the desired views, right-clicking, then selecting Modeling-Create Materialized Views.
Next, generate the DDL for your physical model materialization target tables. This can be done by selecting the model, right clicking, then choosing Export->Metadata Modeling->Data Definition Language (DDL) File. Use this script to create the chema for your materialization target on your source.
Determine a load and refresh strategy. With the schema created the simplest approach is to load the data. You can even load it through Red Hat JBoss Data Virtualization: insert into target_table select * from matview option nocache matview
That however may be too simplistic because your index creation may perform better if deferred until after the table has been created. Also full snapshot refreshes are best done to a staging table then swapping it for the existing physical table to ensure that the refresh does not impact user queries and to ensure that the table is valid prior to use.
Metadata-Based Materialization Management

Users when they are designing their views, they can define additional metadata on their views to control the loading and refreshing of external materialization cache. This option provides a limited but a powerful way to manage the materialization views. For this purpose, SYSADMIN Schema model in your VDB defines three stored procedures (loadMatView, updateMatView, matViewStatus) in its schema. Based on the defined metadata on the view, and these SYSADMIN procedures a simple scheduler automatically starts during the VDB deployment and loads and keeps the cache fresh.

To manage and report the loading and refreshing activity of materialization view, Red Hat JBoss Data Virtualization expects the user to define "Status" table with following schema in any one of the source models. Create this table on the physical database, before you do the import of this physical source.
CREATE TABLE status
(
  VDBName varchar(50) not null,
  VDBVersion integer not null,
  SchemaName varchar(50) not null,
  Name varchar(256) not null,
  TargetSchemaName varchar(50),
  TargetName varchar(256) not null,
  Valid boolean not null,
  LoadState varchar(25) not null,
  Cardinality long,
  Updated timestamp not null,
  LoadNumber long not null,
  PRIMARY KEY (VDBName, VDBVersion, SchemaName, Name)
);

Note

MariaDB have Silent Column Changes function, according to MariaDB document, 'long' type will silently change to 'MEDIUMTEXT' , so If execute above schema in MariaDB, 'Cardinality' and 'LoadNumber' column should change to 'bigint' type.
Create Views and corresponding physical materialized target tables in Designer or using DDL in Dynamic VDB. This can be done through setting the materialized and target table manually, or by selecting the desired views, right clicking, then selecting Modeling->"Create Materialized Views" in the Designer.
Define the following extension properties on the view.
Table 2.1. Extension Properties
Property Description Optional Default
teiid_rel:ALLOW_MATVIEW_MANAGEMENT
Allow Red Hat JBoss Data Virtualization-based management
False
False
teiid_rel:MATVIEW_STATUS_TABLE
fully qualified Status Table Name defined above
False
NA
teiid_rel:MATVIEW_BEFORE_LOAD_SCRIPT
semi-colon(;) separated DDL/DML commands to run before the actual load of the cache, typically used to truncate staging table
True
When not defined, no script will be run
teiid_rel:MATVIEW_LOAD_SCRIPT
semi-colon(;) separated DDL/DML commands to run for loading of the cache
True
will be determined based on view transformation
teiid_rel:MATVIEW_AFTER_LOAD_SCRIPT
semi-colon(;) separated DDL/DML commands to run after the actual load of the cache. Typically used to rename staging table to actual cache table. Required when MATVIEW_LOAD_SCRIPT is not defined in order to copy data from the teiid_rel:MATVIEW_STAGE_TABLE the MATVIEW table.
True
When not defined, no script will be run
teiid_rel:MATVIEW_SHARE_SCOPE
Allowed values are {NONE, VDB, SCHEMA}, which define if the cached contents are shared among different VDB versions and different VDBs as long as schema names match
True
None
teiid_rel:MATERIALIZED_STAGE_TABLE
When MATVIEW_LOAD_SCRIPT property not defined, Red Hat JBoss Data Virtualization loads the cache contents into this table. Required when MATVIEW_LOAD_SCRIPT not defined
False
NA
teiid_rel:ON_VDB_START_SCRIPT
DML commands to run start of vdb
True
NA
teiid_rel:ON_VDB_DROP_SCRIPT
DML commands to run at VDB un-deploy; typically used for cleaning the cache/status tables
True
NA
teiid_rel:MATVIEW_ONERROR_ACTION
Action to be taken when mat view contents are requested but cache is invalid. Allowed values are (THROW_EXCEPTION = throws an exception, IGNORE = ignores the warning and supplied invalidated data, WAIT = waits until the data is refreshed and valid then provides the updated data)
True
WAIT
teiid_rel:MATVIEW_TTL
time to live in milliseconds. Provide property or cache hint on view transformation - property takes precedence.
True
2^63 milliseconds - effectively the table will not refresh, but will be loaded a single time initially
Once the VDB (with a model with the properties specified above) has been defined and deployed, the following sequence of events will take place.
Upon the VDB deployment, teiid_rel:ON_VDB_START_SCRIPT will be run on completion of the deployment.
Based on the teiid_rel:MATVIEW_TTL defined a scheduler entry will be created to run SYSADMIN.loadMatView procedure, which loads the cache contents.
This procedure first inserts/updates an entry in teiid_rel:MATVIEW_STATUS_TABLE, which indicates that the cache is being loaded, then teiid_rel:MATVIEW_BEFORE_LOAD_SCRIPT will be run if defined. Next, teiid_rel:MATVIEW_LOAD_SCRIPT will be run if defined, otherwise one will be automatically created based on the view's transformation logic. Then, teiid_rel:MATVIEW_AFTER_LOAD_SCRIPT will be run, to close out and create any indexes on the mat view table.
The procedure then sets the teiid_rel:MATVIEW_STATUS_TABLE entry to "LOADED" and valid.
Based on the teiid_rel:MATVIEW_TTL, the SYSADMIN.matViewStatus is run by the Scheduler, to queue further cache re-loads.
When VDB is un-deployed (not when server is restarted) the teiid_rel:ON_VDB_DROP_SCRIPT script will be run.
Run the SYSADMIN.updateMatView procedure at any time to partially update the cache contents rather than complete refresh of contents with SYSADMIN.loadMatview procedure. When partial update is run the cache expiration time is renewed for new term based on Cache Hint again.
Here is a sample dynamic VDB:
<?xml version="1.0" encoding="UTF-8" standalone="yes"?>
<vdb name="sakila" version="1">
    <description>Shows how to call JPA entities</description>
 
    <model name="pg">
        <source name="pg" translator-name="postgresql-override" connection-jndi-name="java:/sakila-ds"/>
    </model>
 
    <model name="sakila" type="VIRTUAL">
    <metadata type="DDL"><![CDATA[
        CREATE VIEW actor (
           actor_id integer,
           first_name varchar(45) NOT NULL,
           last_name varchar(45) NOT NULL,
           last_update timestamp NOT NULL
        ) OPTIONS (MATERIALIZED 'TRUE', UPDATABLE 'TRUE',
                MATERIALIZED_TABLE 'pg.public.mat_actor',
                "teiid_rel:MATERIALIZED_STAGE_TABLE" 'pg.public.mat_actor_staging',
                "teiid_rel:ALLOW_MATVIEW_MANAGEMENT" 'true',
                "teiid_rel:MATVIEW_STATUS_TABLE" 'pg.public.status',
                "teiid_rel:MATVIEW_BEFORE_LOAD_SCRIPT" 'execute pg.native(''truncate table mat_actor_staging'');',
                "teiid_rel:MATVIEW_AFTER_LOAD_SCRIPT" 'execute pg.native(''ALTER TABLE mat_actor RENAME TO mat_actor_temp'');execute pg.native(''ALTER TABLE mat_actor_staging RENAME TO mat_actor'');execute pg.native(''ALTER TABLE mat_actor_temp RENAME TO mat_actor_staging;'')',
                "teiid_rel:MATVIEW_SHARE_SCOPE" 'NONE',
                "teiid_rel:MATVIEW_ONERROR_ACTION" 'THROW_EXCEPTION',
                "teiid_rel:MATVIEW_TTL" 300000,
                "teiid_rel:ON_VDB_DROP_SCRIPT" 'DELETE FROM pg.public.status WHERE Name=''actor'' AND schemaname = ''sakila''')
            AS SELECT actor_id, first_name, last_name, last_update from pg."public".actor;
     
    </metadata>
    </model>
    <translator name="postgresql-override" type="postgresql">
        <property name="SupportsNativeQueries" value="true"/>
    </translator>
</vdb>

2.2.1. Configure External Materialization In Teiid Designer

  1. Build a VDB using the Teiid Designer for your use case.
  2. Identify all the "Virtual Tables", that you think can use caching,
  3. Click on the table, then in the Properties panel, switch the Materialized property to "true".
  4. Right click on each materialized table, then choose Modeling - Create Materialized Views.
  5. Click on ... button on the Materialization Model input box.
  6. Select a "physical model" that already exists or create a new name for "physical model".
  7. Click Finish.
    This will create the new model (if applicable) and a table with exact schema as your selected virtual table.
  8. Verify that the "Materialization Table" property is now updated with name of table that has just been created.
  9. Navigate to the new materialized table that has been created, and click on "Name In Source" property and change it from "MV1000001" to "mv_{your_table_name}". Typically this could be same name as your virtual table name, (for example, you might name it "mv_UpdateProduct".)
  10. Save your model.

    Note

    The data source this materialized view physical model represents will be the data source for storing the materialized tables. You can select different "physical models" for different materialized tables, creating multiple places to store your materialized tables.
  11. Once you are have finished creating all materialized tables, right click on each model (in most cases this will be a single physical model used for all the materialized views), then use Export - Teiid Designer - Data Definition Language (DDL) File to generate the DDL for the physical model.
  12. Select the type of the database and DDL file name and click Finish.
    A DDL file that contains all of the "create table" commands is generated..
  13. Use your favorite "client" tool for your database and create the database using the DDL file created.
  14. Go back to your VDB and configure the data source and translator for the "materialized" physical model to the database you just created.
  15. Once finished, deploy the VDB to the Red Hat JBoss Data Virtualization Server and make sure that it is correctly configured and active.

Important

It is important to ensure that the key/index information is defined as this will be used by the materialization process to enhance the performance of the materialized table.
Red Hat logoGithubRedditYoutubeTwitter

Learn

Try, buy, & sell

Communities

About Red Hat Documentation

We help Red Hat users innovate and achieve their goals with our products and services with content they can trust. Explore our recent updates.

Making open source more inclusive

Red Hat is committed to replacing problematic language in our code, documentation, and web properties. For more details, see the Red Hat Blog.

About Red Hat

We deliver hardened solutions that make it easier for enterprises to work across platforms and environments, from the core datacenter to the network edge.

© 2024 Red Hat, Inc.