For OceanBase Database V4.3.5, automatic management of materialized view logs (mlogs) is supported starting with V4.3.5 BP4.
Automatic management of mlogs includes two main aspects:
- When a materialized view is created, the system analyzes its dependencies on base tables and automatically creates the required mlogs.
- The system periodically trims mlogs in the background, deletes mlogs that are no longer needed, and optimizes the column sets in mlogs to reduce maintenance overhead.
Limitations
Mlogs are automatically created or updated only when a materialized view is explicitly declared as a materialized view with incremental refresh (by specifying REFRESH FAST) or a real-time materialized view (by specifying ENABLE ON QUERY COMPUTATION).
Considerations
When updating an mlog definition, OceanBase Database creates a new mlog table and replaces the original one. During this process, an incremental refresh is performed on all associated incremental refresh materialized views to flush incremental data from the original mlog into the materialized views, ensuring safe replacement. If a base table is associated with many materialized views and contains substantial incremental data, updating the mlog definition may be time-consuming. Please be aware of this potential impact in advance.
It is recommended not to set the
mlog_trim_intervaltoo short, as this may cause mlogs to be mistakenly trimmed. If this occurs, you may need to recreate or update the mlog when creating a materialized view.
Related configuration
OceanBase Database provides two parameters to control mlog automatic management:
- enable_mlog_auto_maintenance: Controls whether automatic management of materialized view logs is enabled.
- mlog_trim_interval: Specifies the interval for scheduling automatic mlog trimming tasks.
Example
Enable the mlog auto management feature.
Note
In OceanBase Database V4.3.5 BP4:
- For a new tenant, the default value of the
enable_mlog_auto_maintenanceparameter isTrue, which means the mlog auto management feature is enabled by default. - For a tenant upgraded from a version earlier than V4.3.5 BP4, the default value of the
enable_mlog_auto_maintenanceparameter isFalse, which means the mlog auto management feature is disabled by default.
obclient> ALTER SYSTEM SET enable_mlog_auto_maintenance = True;
Example 1: Automatically create an mlog
Create a table named
test_tbl1.obclient> CREATE TABLE test_tbl1(col1 INT, col2 INT, col3 INT);Create a materialized view with incremental refresh named
mv_test_tbl1on thetest_tbl1table. OceanBase Database automatically creates an mlog for thecol2column of thetest_tbl1table.obclient> CREATE MATERIALIZED VIEW mv_test_tbl1 REFRESH FAST AS SELECT col2, count(*) cnt FROM test_tbl1 GROUP BY col2;View the information about the materialized view logs on the
test_tbl1table.obclient> DESC mlog$_test_tbl1;The return result is as follows:
+------------+-----------------+------+------+---------+-------+ | Field | Type | Null | Key | Default | Extra | +------------+-----------------+------+------+---------+-------+ | col2 | int(11) | YES | | NULL | | | SEQUENCE$$ | bigint(20) | NO | PRI | NULL | | | DMLTYPE$$ | varchar(1) | YES | | NULL | | | OLD_NEW$$ | varchar(1) | YES | | NULL | | | M_ROW$$ | bigint unsigned | NO | PRI | NULL | | +------------+-----------------+------+------+---------+-------+ 5 rows in set
Example 2: Automatically update the mlog definition
Create a table named
test_tbl2.obclient> CREATE TABLE test_tbl2(col1 INT, col2 INT, col3 INT);Create a materialized view with incremental refresh named
mv1_test_tbl2on thetest_tbl2table. OceanBase Database automatically creates an mlog for thecol2column on thetest_tbl2table.obclient> CREATE MATERIALIZED VIEW mv1_test_tbl2 REFRESH FAST AS SELECT col2, count(*) cnt FROM test_tbl2 GROUP BY col2;View the information about the materialized view log on the
test_tbl2table.obclient> DESC mlog$_test_tbl2;The return result is as follows:
+------------+-----------------+------+------+---------+-------+ | Field | Type | Null | Key | Default | Extra | +------------+-----------------+------+------+---------+-------+ | col2 | int(11) | YES | | NULL | | | SEQUENCE$$ | bigint(20) | NO | PRI | NULL | | | DMLTYPE$$ | varchar(1) | YES | | NULL | | | OLD_NEW$$ | varchar(1) | YES | | NULL | | | M_ROW$$ | bigint unsigned | NO | PRI | NULL | | +------------+-----------------+------+------+---------+-------+ 5 rows in setCreate a materialized view with incremental refresh named
mv2_test_tbl2on thetest_tbl2table. OceanBase Database detects that the current mlog table contains only thecol2column and modifies the existing mlog definition to add thecol3column to the mlog table.obclient> CREATE MATERIALIZED VIEW mv2_test_tbl2 REFRESH FAST AS SELECT col3, count(*) cnt FROM test_tbl2 GROUP BY col3;View the information about the materialized view log on the
test_tbl2table again. You can observe that the mlog table definition for thetest_tbl2table contains thecol2andcol3columns.obclient> DESC mlog$_test_tbl2;The return result is as follows:
+------------+-----------------+------+------+---------+-------+ | Field | Type | Null | Key | Default | Extra | +------------+-----------------+------+------+---------+-------+ | col2 | int(11) | YES | | NULL | | | col3 | int(11) | YES | | NULL | | | SEQUENCE$$ | bigint(20) | NO | PRI | NULL | | | DMLTYPE$$ | varchar(1) | YES | | NULL | | | OLD_NEW$$ | varchar(1) | YES | | NULL | | | M_ROW$$ | bigint unsigned | NO | PRI | NULL | | +------------+-----------------+------+------+---------+-------+ 6 rows in set
Example 3: Automatic mlog pruning
Create a table named
test_tbl3.obclient> CREATE TABLE test_tbl3(col1 INT, col2 INT, col3 INT);Create a materialized view with incremental refresh named
mv1_test_tbl3on thetest_tbl3table. OceanBase Database automatically creates an mlog for thecol2column on thetest_tbl3table.obclient> CREATE MATERIALIZED VIEW mv1_test_tbl3 REFRESH FAST AS SELECT col2, count(*) cnt FROM test_tbl3 GROUP BY col2;Create a materialized view with incremental refresh named
mv2_test_tbl3on thetest_tbl3table. OceanBase Database detects that the current mlog table contains only thecol2column and modifies the existing mlog definition by adding thecol3column to the mlog table.obclient> CREATE MATERIALIZED VIEW mv2_test_tbl3 REFRESH FAST AS SELECT col3, count(*) cnt FROM test_tbl3 GROUP BY col3;View the information about the materialized view logs on the
test_tbl3table. You can observe that the mlog table definition for thetest_tbl3table contains thecol2andcol3columns.obclient> DESC mlog$_test_tbl3;The return result is as follows:
+------------+-----------------+------+------+---------+-------+ | Field | Type | Null | Key | Default | Extra | +------------+-----------------+------+------+---------+-------+ | col2 | int(11) | YES | | NULL | | | col3 | int(11) | YES | | NULL | | | SEQUENCE$$ | bigint(20) | NO | PRI | NULL | | | DMLTYPE$$ | varchar(1) | YES | | NULL | | | OLD_NEW$$ | varchar(1) | YES | | NULL | | | M_ROW$$ | bigint unsigned | NO | PRI | NULL | | +------------+-----------------+------+------+---------+-------+ 6 rows in setChange the mlog pruning interval to observe the pruning result faster.
obclient> ALTER SYSTEM SET mlog_trim_interval = '5s';Drop the materialized view
mv1_test_tbl3.obclient> DROP MATERIALIZED VIEW mv1_test_tbl3;After 5 seconds, check the information about the materialized view logs on the
test_tbl3table. You can observe that the mlog table definition for thetest_tbl3table contains only thecol3column.obclient> DESC mlog$_test_tbl3;The return result is as follows:
+------------+-----------------+------+------+---------+-------+ | Field | Type | Null | Key | Default | Extra | +------------+-----------------+------+------+---------+-------+ | col3 | int(11) | YES | | NULL | | | SEQUENCE$$ | bigint(20) | NO | PRI | NULL | | | DMLTYPE$$ | varchar(1) | YES | | NULL | | | OLD_NEW$$ | varchar(1) | YES | | NULL | | | M_ROW$$ | bigint unsigned | NO | PRI | NULL | | +------------+-----------------+------+------+---------+-------+ 5 rows in setDrop the materialized view
mv2_test_tbl3.obclient> DROP MATERIALIZED VIEW mv2_test_tbl3;After 5 seconds, check the information about the materialized view logs on the
test_tbl3table. You can observe that the mlog table for thetest_tbl3table no longer exists.obclient> DESC mlog$_test_tbl3;The return result is as follows:
ERROR 1146 (42S02): Table 'test_db.mlog$_test_tbl3' doesn't existRestore the mlog pruning interval.
obclient> ALTER SYSTEM SET mlog_trim_interval = '1d';