When automatic load balancing cannot meet your aggregation and dispersion requirements for a specific partition, you can manually transfer a partition.
Limitations and considerations
You must have the
ALTER SYSTEMpermission to transfer a partition. For more information about permissions, see Users and permissions.You can perform the TRANSFER PARTITION operation only in the primary tenant to transfer only a partition of a user tenant.
After you set the
enable_transferparameter tofalseto disable the transfer feature for a tenant, an error will be returned if you execute theTRANSFER PARTITIONstatement for this tenant, and a partition transfer task initiated by a successfully executedTRANSFER PARTITIONstatement may be canceled.You cannot perform partition transfer for a system table.
You cannot perform partition transfer for a user table in the sys tenant.
You cannot transfer a normal table to a broadcast log stream or transfer a replicated table to a normal log stream.
You cannot transfer a non-independent partition, such as a partition of a local index table or large object (LOB) table.
If a transfer operation is in progress for a partition, you cannot initiate another transfer operation for this partition before the current transfer operation is completed.
If a load balancing job (BALANCE_JOB) is in progress in the current cluster, a manually initiated partition transfer task will not be immediately scheduled. If you want to schedule the partition transfer task as soon as possible, you can cancel the load balancing job. For more information, see Cancel a load balancing job.
Prerequisites
Before transferring a partition, you must enable the transfer feature. You can set the
enable_transferparameter to enable or disable the transfer feature. The default value of the parameter istrue, indicating that the transfer feature is enabled. For more information about theenable_transferparameter, see enable_transfer.The partition transfer policy may conflict with the automatic balancing policy. To ensure a fixed partition location, we recommend that you disable the automatic balancing policy before you perform a partition transfer, that is, set
enable_rebalancetofalsefor the corresponding tenant. For more information about theenable_rebalanceparameter, see enable_rebalance.Partition transfer itself is not subject to the
enable_rebalanceparameter. However, if bothenable_rebalanceandenable_transferare set totrue, after a user transfers a partition to the corresponding log stream, the system may transfer the partition to another log stream based on the automatic balancing policy.
Initiate a partition transfer from the sys tenant
Log in to the
systenant of the cluster as therootuser.Note that you must specify the corresponding parameters in the following sample code based on your actual database configurations.
obclient -h10.xx.xx.xx -P2883 -uroot@sys#obdemo -p***** -AQuery the
DBA_OB_TENANTSview for the ID of the target tenant.obclient [oceanbase]> SELECT TENANT_ID FROM oceanbase.DBA_OB_TENANTS WHERE TENANT_NAME = 'oracle_tenant';The query result is as follows:
+-----------+ | TENANT_ID | +-----------+ | 1006 | +-----------+ 1 row in setConfirm the partition information.
You can query the
CDB_OB_TABLE_LOCATIONSview forTABLET_ID,OBJECT_ID, andLS_IDof the specified partition in the table.Query
TABLET_ID,OBJECT_ID, andLS_IDof a specified partition in a non-partitioned tableAssume that non-partitioned table
T1exists in theoracle_tenanttenant. A sample query is as follows:obclient [oceanbase]> SELECT TABLE_ID AS TABLE_ID, OBJECT_ID, TABLET_ID, LS_ID FROM oceanbase.CDB_OB_TABLE_LOCATIONS WHERE TENANT_ID = 1006 AND DATABASE_NAME = 'SYS' AND TABLE_NAME= 'T1' LIMIT 1;The query result is as follows:
+----------+-----------+-----------+-------+ | TABLE_ID | OBJECT_ID | TABLET_ID | LS_ID | +----------+-----------+-----------+-------+ | 500002 | 500002 | 200001 | 1001 | +----------+-----------+-----------+-------+ 1 row in setQuery
TABLET_ID,OBJECT_ID, andLS_IDof a specified partition in a partitioned tableYou need to specify only the partition name for the query.
Assume that partitioned table
TBL1_LOG_Rexists in theoracle_tenanttenant. A sample query is as follows:obclient [SYS]> CREATE TABLE tbl1_log_r(log_id INT,log_date DATE NOT NULL DEFAULT SYSDATE) PARTITION BY RANGE(log_date) (PARTITION M202001 VALUES LESS THAN(TO_DATE('2020/02/01','YYYY/MM/DD')) , PARTITION M202002 VALUES LESS THAN(TO_DATE('2020/03/01','YYYY/MM/DD')) , PARTITION M202003 VALUES LESS THAN(TO_DATE('2020/04/01','YYYY/MM/DD')) , PARTITION M202004 VALUES LESS THAN(TO_DATE('2020/05/01','YYYY/MM/DD')) , PARTITION M202005 VALUES LESS THAN(TO_DATE('2020/06/01','YYYY/MM/DD')) , PARTITION M202006 VALUES LESS THAN(TO_DATE('2020/07/01','YYYY/MM/DD')) , PARTITION M202007 VALUES LESS THAN(TO_DATE('2020/08/01','YYYY/MM/DD')) , PARTITION M202008 VALUES LESS THAN(TO_DATE('2020/09/01','YYYY/MM/DD')) , PARTITION M202009 VALUES LESS THAN(TO_DATE('2020/10/01','YYYY/MM/DD')) , PARTITION M202010 VALUES LESS THAN(TO_DATE('2020/11/01','YYYY/MM/DD')) , PARTITION M202011 VALUES LESS THAN(TO_DATE('2020/12/01','YYYY/MM/DD')) , PARTITION M202012 VALUES LESS THAN(TO_DATE('2021/01/01','YYYY/MM/DD')) , PARTITION MMAX VALUES LESS THAN (MAXVALUE) );The following sample code queries related information about the
M202005partition in the partitioned table.obclient [oceanbase]> SELECT TABLE_ID AS TABLE_ID, OBJECT_ID, TABLET_ID, LS_ID FROM oceanbase.CDB_OB_TABLE_LOCATIONS WHERE TENANT_ID = 1006 AND DATABASE_NAME = 'SYS' AND TABLE_NAME= 'TBL1_LOG_R' AND PARTITION_NAME = 'M202005' LIMIT 1;The query result is as follows:
+----------+-----------+-----------+-------+ | TABLE_ID | OBJECT_ID | TABLET_ID | LS_ID | +----------+-----------+-----------+-------+ | 500003 | 500009 | 200006 | 1002 | +----------+-----------+-----------+-------+ 1 row in setQuery
TABLET_ID,OBJECT_ID, andLS_IDof a specified subpartition in a subpartitioned tableYou need to specify both the partition and subpartition names for the query.
Assume that subpartitioned table
T2_F_RLexists in theoracle_tenanttenant. A sample query is as follows:obclient [SYS]> CREATE TABLE t2_f_rl(col1 INT,col2 VARCHAR2(50)) PARTITION BY RANGE(col1) SUBPARTITION BY LIST(col2) (PARTITION p0 VALUES LESS THAN(100) (SUBPARTITION sp0 VALUES('01'), SUBPARTITION sp1 VALUES('02') ), PARTITION p1 VALUES LESS THAN(200) (SUBPARTITION sp2 VALUES('01'), SUBPARTITION sp3 VALUES('02'), SUBPARTITION sp4 VALUES('03') ) );The following sample code queries related information about the
SP2subpartition in the subpartitioned table.obclient [oceanbase]> SELECT TABLE_ID AS TABLE_ID, OBJECT_ID, TABLET_ID, LS_ID FROM oceanbase.CDB_OB_TABLE_LOCATIONS WHERE TENANT_ID = 1006 AND DATABASE_NAME = 'SYS' AND TABLE_NAME= 'T2_F_RL' AND PARTITION_NAME = 'P1' AND SUBPARTITION_NAME = 'SP2' LIMIT 1;The query result is as follows:
+----------+-----------+-----------+-------+ | TABLE_ID | OBJECT_ID | TABLET_ID | LS_ID | +----------+-----------+-----------+-------+ | 500018 | 500023 | 200017 | 1003 | +----------+-----------+-----------+-------+ 1 row in set
Select the transfer destination.
Query the
CDB_OB_LSview for the log stream status and information of the tenant.obclient [oceanbase]> SELECT * FROM oceanbase.CDB_OB_LS WHERE TENANT_ID = 1006;The query result is as follows:
+-----------+-------+--------+--------------+---------------+-------------+---------------------+----------+---------------------+---------------------+------+ | TENANT_ID | LS_ID | STATUS | PRIMARY_ZONE | UNIT_GROUP_ID | LS_GROUP_ID | CREATE_SCN | DROP_SCN | SYNC_SCN | READABLE_SCN | FLAG | +-----------+-------+--------+--------------+---------------+-------------+---------------------+----------+---------------------+---------------------+------+ | 1006 | 1 | NORMAL | zone1 | 0 | 0 | NULL | NULL | 1701244663685197789 | 1701244663685197789 | | | 1006 | 1001 | NORMAL | zone1 | 1006 | 1001 | 1701239786827662637 | NULL | 1701244663685197789 | 1701244663685197789 | | | 1006 | 1002 | NORMAL | zone1 | 1007 | 1002 | 1701239786831568305 | NULL | 1701244664066906860 | 1701244664066906859 | | | 1006 | 1003 | NORMAL | zone1 | 1008 | 1003 | 1701239786834300282 | NULL | 1701244664175263949 | 1701244664175263948 | | +-----------+-------+--------+--------------+---------------+-------------+---------------------+----------+---------------------+---------------------+------+ 4 rows in setQuery the
CDB_OB_TABLET_TO_LSview for the distribution of tablets on the log streams.obclient [oceanbase]> SELECT LS_ID, COUNT(*) AS C FROM oceanbase.CDB_OB_TABLET_TO_LS WHERE TENANT_ID = 1006 GROUP BY LS_ID;The query result is as follows:
+-------+------+ | LS_ID | C | +-------+------+ | 1 | 578 | | 1001 | 7 | | 1002 | 5 | | 1003 | 7 | +-------+------+ 4 rows in setSelect an appropriate log stream as the transfer destination based on the preceding information.
Execute the following statement to perform partition transfer:
ALTER SYSTEM TRANSFER PARTITION TABLE_ID [=] table_id, OBJECT_ID [=] object_id TO LS ls_id TENANT = 'tenant_name';where:
table_idindicates the ID of the table.object_idindicates the unique ID of the partition.ls_idindicates the ID of the log stream to which the partition is to be transferred.tenant_nameindicates the tenant to which the partition to be transferred belongs.
The following sample code transfers the
M202005partition of theTBL1_LOG_Rtable in theSYSdatabase from log stream1002to log stream1003in theoracle_tenanttenant.obclient [oceanbase]> ALTER SYSTEM TRANSFER PARTITION TABLE_ID = 500003, OBJECT_ID = 500009 TO LS 1003 TENANT = 'oracle_tenant';After the statement is executed, query the status of the partition transfer task.
Query the
CDB_OB_TRANSFER_PARTITION_TASKSview for theTASK_ID,TRANSFER_TASK_ID, andBALANCE_JOB_IDvalues of the task.The
CDB_OB_TRANSFER_PARTITION_TASKSview displays the ongoing partition transfer tasks of all tenants. A sample query is as follows:obclient [oceanbase]> SELECT TASK_ID, BALANCE_JOB_ID, TRANSFER_TASK_ID, STATUS FROM oceanbase.CDB_OB_TRANSFER_PARTITION_TASKS WHERE TENANT_ID = 1006 AND TABLE_ID = 500003 AND OBJECT_ID = 500009;A sample query result is as follows:
+---------+----------------+------------------+--------+ | TASK_ID | BALANCE_JOB_ID | TRANSFER_TASK_ID | STATUS | +---------+----------------+------------------+--------+ | 1 | 17304 | 1 | DOING | +---------+----------------+------------------+--------+ 1 row in setThe value of the
STATUSfield indicates the status of the task. Valid values:WAITING: The task is waiting to be scheduled.INIT: A load balancing job has been constructed for the task. You can view the execution progress of the load balancing job based on itsBALANCE_JOB_IDvalue.DOING: The task is in progress. You can view the task based onTRANSFER_TASK_ID, which will change several times. A partition transfer task involves multiple transfers.
If the query on the
CDB_OB_TRANSFER_PARTITION_TASKSview returns an empty result set, you can query theCDB_OB_TRANSFER_PARTITION_TASK_HISTORYview for the task execution result.Query the
CDB_OB_BALANCE_JOBSorCDB_OB_BALANCE_JOB_HISTORYview based on the obtainedBALANCE_JOB_IDvalue to confirm the execution status of the associated load balancing job.The
CDB_OB_BALANCE_JOBSview displays the ongoing load balancing jobs of all tenants. Each tenant can have only one running load balancing job (BALANCE_JOB) at a time. A load balancing job generates multiple transfer tasks (TRANSFER_TASK). TheCDB_OB_BALANCE_JOB_HISTORYview displays the historical load balancing jobs of all tenants. A sample query is as follows:obclient [oceanbase]> SELECT * FROM oceanbase.CDB_OB_BALANCE_JOBS WHERE JOB_ID = 17304;obclient [oceanbase]> SELECT * FROM oceanbase.CDB_OB_BALANCE_JOB_HISTORY WHERE JOB_ID = 17304;You must replace
17304with theBALANCE_JOB_IDvalue obtained in previous steps.The
STATUScolumn in the query result indicates the execution status of the load balancing job. Valid values:DOING: The load balancing job is in progress.COMPLETED: The load balancing job was successfully executed.CANCELING: The load balancing job is being canceled.CANCELED: The load balancing job has been canceled.
Query the
CDB_OB_TRANSFER_TASKSorCDB_OB_TRANSFER_TASK_HISTORYview based on the obtainedTRANSFER_TASK_IDvalue for the execution status of the transfer task.The
CDB_OB_TRANSFER_TASKSview displays the ongoing transfer tasks of all tenants. Multiple ongoing transfer tasks (TRANSFER_TASK) that belong to the same load balancing job (BALANCE_JOB) can exist concurrently in a tenant. TheCDB_OB_TRANSFER_TASK_HISTORYview displays the historical transfer tasks of all tenants. A sample query is as follows:obclient [oceanbase]> SELECT * FROM oceanbase.CDB_OB_TRANSFER_TASKS WHERE TASK_ID = 1;obclient [oceanbase]> SELECT * FROM oceanbase.CDB_OB_TRANSFER_TASK_HISTORY WHERE TASK_ID = 1;You must replace
1with theTRANSFER_TASK_IDvalue obtained in previous steps.The
STATUScolumn in the query result indicates the execution status of the transfer task. Valid values:INIT: The task is being created.START: The task starts to be executed.DOING: The task is in progress.ABORTED: The task was aborted.COMPLETED: The task was successfully executed.FAILED: The task failed.CANCELED: The task has been canceled.
Query the
CDB_OB_TRANSFER_PARTITION_TASK_HISTORYview based on the obtainedTASK_IDvalue for the execution result of the partition transfer task.The
CDB_OB_TRANSFER_PARTITION_TASK_HISTORYview displays the historical partition transfer tasks of all tenants.obclient [oceanbase]> SELECT * FROM oceanbase.CDB_OB_TRANSFER_PARTITION_TASK_HISTORY WHERE TASK_ID = 1;You must replace
1with theTASK_IDvalue obtained in previous steps.The
STATUScolumn in the query result indicates the execution result of the partition transfer task. Valid values:COMPLETED: The task was successfully executed.FAILED: The task failed. You can view the cause of the failure in theCOMMENTcolumn. The following information is common in theCOMMENTfield:LS not exist or may be in DROPPING/WAIT_OFFLINE status: The destination log stream does not exist or is in theDROPPINGorWAITOFFLINEstate.LS status is not NORMAL or is in BLOCK_TABLET_IN state: The destination log stream is not in theNORMALstate. For example, it may be in theCREATINGorCREATEDstate, or the log stream is in theBLOCK_TABLET_INstate and cannot accept new partitions.Table has beed dropped: The table of the partition to be transferred is deleted.Partition has beed dropped: The partition to be transferred is deleted.Partition is already in dest LS: The partition is already on the transfer destination.Need retry, partition may be dropped: The partition is deleted when the transfer task is executed. The system will re-check whether the partition exists when generating the next load balancing task.Need retry, partition may be dropped or be transferred: The partition does not exist when the transfer task is executed. The partition may have been deleted or no longer exist on the source log stream. The system will re-check whether the partition exists when generating the next load balancing task.
After successful execution of the partition transfer task, query the information about the partition again.
obclient [oceanbase]> SELECT TABLE_ID AS TABLE_ID, OBJECT_ID, TABLET_ID, LS_ID FROM oceanbase.CDB_OB_TABLE_LOCATIONS WHERE TENANT_ID = 1006 AND DATABASE_NAME = 'SYS' AND TABLE_NAME= 'TBL1_LOG_R' AND PARTITION_NAME = 'M202005' LIMIT 1;The query result is as follows:
+----------+-----------+-----------+-------+ | TABLE_ID | OBJECT_ID | TABLET_ID | LS_ID | +----------+-----------+-----------+-------+ | 500003 | 500009 | 200006 | 1003 | +----------+-----------+-----------+-------+ 1 row in setThe result shows that the
M202005partition of theTBL1_LOG_Rtable in theSYSdatabase has been transferred from log stream1002to log stream1003.
Initiate a partition transfer from a user tenant
This section takes the mysql_tenant user tenant as an example.
Connect to the database as the tenant administrator of the MySQL tenant.
Note that you must specify the corresponding parameters in the following sample code based on your actual database configurations.
obclient -h10.xx.xx.xx -P2883 -uroot@mysql_tenant#obdemo -p***** -AConfirm the partition information.
Query the
DBA_OB_TABLE_LOCATIONSview to obtain the values ofTABLET_ID,OBJECT_ID, andLS_IDof the specified partition.Query
TABLET_ID,OBJECT_ID, andLS_IDvalues of a non-partitioned tableAssume that
mysql_tenanthas a non-partitioned table namedt1. Here is a query example:obclient [test]> SELECT TABLE_ID AS TABLE_ID, OBJECT_ID, TABLET_ID, LS_ID FROM oceanbase.DBA_OB_TABLE_LOCATIONS WHERE DATABASE_NAME = 'test' AND TABLE_NAME= 't1' LIMIT 1;The query result is as follows:
+----------+-----------+-----------+-------+ | TABLE_ID | OBJECT_ID | TABLET_ID | LS_ID | +----------+-----------+-----------+-------+ | 500002 | 500002 | 200001 | 1001 | +----------+-----------+-----------+-------+ 1 row in setQuery
TABLET_ID,OBJECT_ID, andLS_IDvalues of a partitioned tableYou need to specify only the partition name for the query. Here is an example:
Assume that
mysql_tenanthas a partitioned table namedtbl1_l.obclient [test]> CREATE TABLE tbl1_l (col1 BIGINT PRIMARY KEY,col2 VARCHAR(50)) PARTITION BY LIST(col1) (PARTITION p0 VALUES IN (1, 2, 3), PARTITION p1 VALUES IN (5, 6), PARTITION p2 VALUES IN (DEFAULT) );The following example shows how to query the
p1partition of the partitioned table:obclient [oceanbase]> SELECT TABLE_ID AS TABLE_ID, OBJECT_ID, TABLET_ID, LS_ID FROM oceanbase.DBA_OB_TABLE_LOCATIONS WHERE DATABASE_NAME = 'test' AND TABLE_NAME= 'tbl1_l' AND PARTITION_NAME = 'p1' LIMIT 1;The query result is as follows:
+----------+-----------+-----------+-------+ | TABLE_ID | OBJECT_ID | TABLET_ID | LS_ID | +----------+-----------+-----------+-------+ | 500012 | 500014 | 200009 | 1001 | +----------+-----------+-----------+-------+ 1 row in setQuery
TABLET_ID,OBJECT_ID, andLS_IDvalues of a subpartitioned tableYou need to specify both the partition and subpartition names for the query.
Assume that
mysql_tenanthas a subpartitioned table namedt2_f_rclc.obclient [test]> CREATE TABLE t2_f_rclc (col1 INT,col2 INT) PARTITION BY RANGE COLUMNS(col1) SUBPARTITION BY LIST COLUMNS(col2) (PARTITION p0 VALUES LESS THAN(100) (SUBPARTITION sp0 VALUES IN(1,3), SUBPARTITION sp1 VALUES IN(4,6), SUBPARTITION sp2 VALUES IN(7,9)), PARTITION p1 VALUES LESS THAN(200) (SUBPARTITION sp3 VALUES IN(1,3), SUBPARTITION sp4 VALUES IN(4,6), SUBPARTITION sp5 VALUES IN(7,9)) );The following example shows how to query the
sp3subpartition in the subpartitioned table:obclient [oceanbase]> SELECT TABLE_ID AS TABLE_ID, OBJECT_ID, TABLET_ID, LS_ID FROM oceanbase.DBA_OB_TABLE_LOCATIONS WHERE DATABASE_NAME = 'test' AND TABLE_NAME= 't2_f_rclc' AND PARTITION_NAME = 'P1' AND SUBPARTITION_NAME = 'sp3' LIMIT 1;The query result is as follows:
+----------+-----------+-----------+-------+ | TABLE_ID | OBJECT_ID | TABLET_ID | LS_ID | +----------+-----------+-----------+-------+ | 500003 | 500009 | 200005 | 1002 | +----------+-----------+-----------+-------+ 1 row in set
Select the transfer destination.
Query the
DBA_OB_LSview to obtain the log stream status and information in the tenant.obclient [oceanbase]> SELECT * FROM oceanbase.DBA_OB_LS;The query result is as follows:
+-------+--------+--------------+---------------+-------------+---------------------+----------+---------------------+---------------------+------+ | LS_ID | STATUS | PRIMARY_ZONE | UNIT_GROUP_ID | LS_GROUP_ID | CREATE_SCN | DROP_SCN | SYNC_SCN | READABLE_SCN | FLAG | +-------+--------+--------------+---------------+-------------+---------------------+----------+---------------------+---------------------+------+ | 1 | NORMAL | zone1 | 0 | 0 | NULL | NULL | 1701247658419109377 | 1701247658419109377 | | | 1001 | NORMAL | zone1 | 1003 | 1001 | 1701239750437064613 | NULL | 1701247658419109376 | 1701247658419109376 | | | 1002 | NORMAL | zone1 | 1004 | 1002 | 1701239750441114919 | NULL | 1701247658223204599 | 1701247658223204599 | | | 1003 | NORMAL | zone1 | 1005 | 1003 | 1701239750443869478 | NULL | 1701247659122731843 | 1701247659030755559 | | +-------+--------+--------------+---------------+-------------+---------------------+----------+---------------------+---------------------+------+ 4 rows in setQuery the
DBA_OB_TABLET_TO_LSview to obtain the tablet distribution on log streams.obclient [oceanbase]> SELECT LS_ID, COUNT(*) AS C FROM oceanbase.DBA_OB_TABLET_TO_LS GROUP BY LS_ID;The query result is as follows:
+-------+------+ | LS_ID | C | +-------+------+ | 1 | 590 | | 1001 | 4 | | 1002 | 3 | | 1003 | 3 | +-------+------+ 4 rows in setSelect an appropriate log stream as the transfer destination based on the preceding information.
Execute the following statement to perform partition transfer:
ALTER SYSTEM TRANSFER PARTITION TABLE_ID [=] table_id, OBJECT_ID [=] object_id TO LS ls_id;where:
table_idindicates the ID of the table.object_idindicates the unique ID of the partition.ls_idindicates the ID of the destination log stream of the transfer.tenant_nameindicates the tenant to which the partition to be transferred belongs.
The following example shows how to transfer the
p1partition of thetbl1_ltable in thetestdatabase of themysql_tenanttenant from the current1001log stream to the1003log stream:obclient [oceanbase]> ALTER SYSTEM TRANSFER PARTITION TABLE_ID = 500012, OBJECT_ID = 500014 TO LS 1003;After the partition transfer command is executed successfully, you can check the task status by querying the following views.
Query the
DBA_OB_TRANSFER_PARTITION_TASKSview to obtain the values ofTASK_ID,TRANSFER_TASK_ID, andBALANCE_JOB_IDof the task.The
DBA_OB_TRANSFER_PARTITION_TASKSview displays the ongoing partition transfer tasks in the current tenant. A sample query is as follows:obclient [oceanbase]> SELECT TASK_ID, BALANCE_JOB_ID, TRANSFER_TASK_ID, STATUS FROM oceanbase.DBA_OB_TRANSFER_PARTITION_TASKS WHERE TABLE_ID = 500012 AND OBJECT_ID = 500014;A sample query result is as follows:
+---------+----------------+------------------+--------+ | TASK_ID | BALANCE_JOB_ID | TRANSFER_TASK_ID | STATUS | +---------+----------------+------------------+--------+ | 1 | 26506 | 1 | DOING | +---------+----------------+------------------+--------+ 1 row in setThe value of the
STATUSfield indicates the status of the task. Valid values:WAITING: The task is waiting to be scheduled.INIT: A load balancing job has been constructed for the task. You can view the execution progress of the load balancing job based on itsBALANCE_JOB_IDvalue.DOING: The task is in progress. You can view the task based onTRANSFER_TASK_ID, which will change several times. A partition transfer task involves multiple transfers.
If the query of the
DBA_OB_TRANSFER_PARTITION_TASKSview returns an empty result, you can query theDBA_OB_TRANSFER_PARTITION_TASK_HISTORYview to check the task result.Query the
DBA_OB_BALANCE_JOBSorDBA_OB_BALANCE_JOB_HISTORYview based on the obtainedBALANCE_JOB_IDvalue to check the execution status of the associated load balancing job.The
DBA_OB_BALANCE_JOBSview displays the load balancing jobs that are being performed in the tenant. Each tenant can have only one running load balancing job (BALANCE_JOB) at a time. A load balancing job generates multiple transfer tasks (TRANSFER_TASK). TheDBA_OB_BALANCE_JOB_HISTORYview displays the history of load balancing jobs that have been performed in the tenant. A sample query is as follows:obclient [oceanbase]> SELECT * FROM oceanbase.DBA_OB_BALANCE_JOBS WHERE JOB_ID = 26506;obclient [oceanbase]> SELECT * FROM oceanbase.DBA_OB_BALANCE_JOB_HISTORY WHERE JOB_ID = 26506;Replace
26506with the obtainedBALANCE_JOB_IDvalue.The
STATUSfield in the query result indicates the execution status of the load balancing job. Valid values:DOING: The load balancing job is in progress.COMPLETED: The load balancing job was successfully executed.CANCELING: The load balancing job is being canceled.CANCELED: The load balancing job has been canceled.
Query the
DBA_OB_TRANSFER_TASKSorDBA_OB_TRANSFER_TASK_HISTORYview based on the obtainedTRANSFER_TASK_IDvalue and check the execution status of the associated transfer task.The
DBA_OB_TRANSFER_TASKSview displays the load balancing tasks that are being performed in the tenant. Multiple ongoing transfer tasks (TRANSFER_TASK) that belong to the same load balancing job (BALANCE_JOB) can exist concurrently in a tenant. TheDBA_OB_TRANSFER_TASK_HISTORYview displays the history of load balancing tasks that have been performed in the tenant. A sample query is as follows:obclient [oceanbase]> SELECT * FROM oceanbase.DBA_OB_TRANSFER_TASKS WHERE TASK_ID = 1;obclient [oceanbase]> SELECT * FROM oceanbase.DBA_OB_TRANSFER_TASK_HISTORY WHERE TASK_ID = 1;You must replace
1with theTRANSFER_TASK_IDvalue obtained in previous steps.The
STATUSfield in the query result indicates the execution status of the transfer task. Valid values:INIT: The task is being created.START: The task starts to be executed.DOING: The task is in progress.ABORTED: The task was aborted.COMPLETED: The task was successfully executed.FAILED: The task failed.CANCELED: The transfer task is canceled.
Query the
DBA_OB_TRANSFER_PARTITION_TASK_HISTORYview based on the obtainedTASK_IDvalue to confirm the result of the partition transfer task.The
DBA_OB_TRANSFER_PARTITION_TASK_HISTORYview displays the historical partition transfer tasks executed in the current tenant. A sample query is as follows:obclient [oceanbase]> SELECT * FROM oceanbase.DBA_OB_TRANSFER_PARTITION_TASK_HISTORY WHERE TASK_ID = 1;You must replace
1with theTASK_IDvalue obtained in previous steps.The
STATUSfield in the query result indicates the execution result of the partition transfer task. Valid values:COMPLETED: The task was successfully executed.FAILED: The task failed. You can view the cause of the failure in theCOMMENTcolumn. The following information is common in theCOMMENTfield:LS not exist or may be in DROPPING/WAIT_OFFLINE status: The destination log stream does not exist or is in theDROPPINGorWAITOFFLINEstate.LS status is not NORMAL or is in BLOCK_TABLET_IN state: The destination log stream is not in theNORMALstate. For example, it may be in theCREATINGorCREATEDstate, or the log stream is in theBLOCK_TABLET_INstate and cannot accept new partitions.Table has been dropped: The table of the partition to be transferred is deleted.Partition has been dropped: The partition to be transferred is deleted.Partition is already in dest LS: The partition is already on the transfer destination.Need retry, partition may be dropped: The partition is deleted when the transfer task is executed. The system will re-check whether the partition exists when generating the next load balancing task.Need retry, partition may be dropped or be transferred: The partition does not exist when the transfer task is executed. The partition may have been deleted or no longer exist on the source log stream. The system will re-check whether the partition exists when generating the next load balancing task.
After successful execution of the partition transfer task, query the information about the partition again.
obclient [oceanbase]> SELECT TABLE_ID AS TABLE_ID, OBJECT_ID, TABLET_ID, LS_ID FROM oceanbase.DBA_OB_TABLE_LOCATIONS WHERE DATABASE_NAME = 'test' AND TABLE_NAME= 'tbl1_l' AND PARTITION_NAME = 'p1' LIMIT 1;The query result is as follows:
+----------+-----------+-----------+-------+ | TABLE_ID | OBJECT_ID | TABLET_ID | LS_ID | +----------+-----------+-----------+-------+ | 500012 | 500014 | 200009 | 1003 | +----------+-----------+-----------+-------+ 1 row in setThe result shows that the
p1partition of thetbl1_ltable in thetestdatabase is transferred from the1001log stream to the1003log stream. The partition transfer operation succeeded.
This section takes the oracle_tenant tenant as an example.
Connect to the database as the tenant administrator of the Oracle tenant.
Note that you must specify the corresponding parameters in the following sample code based on your actual database configurations.
obclient -h10.xx.xx.xx -P2883 -usys@oracle_tenant#obdemo -p***** -AConfirm the partition information.
Query the
DBA_OB_TABLE_LOCATIONSview to obtain the values ofTABLET_ID,OBJECT_ID, andLS_IDof the specified partition.Query
TABLET_ID,OBJECT_ID, andLS_IDvalues of a non-partitioned tableAssume that non-partitioned table
T1exists in theoracle_tenanttenant. A sample query is as follows:obclient [SYS]> SELECT TABLE_ID AS TABLE_ID, OBJECT_ID, TABLET_ID, LS_ID FROM SYS.DBA_OB_TABLE_LOCATIONS WHERE DATABASE_NAME = 'SYS' AND TABLE_NAME= 'T1' AND ROWNUM = 1;The query result is as follows:
+----------+-----------+-----------+-------+ | TABLE_ID | OBJECT_ID | TABLET_ID | LS_ID | +----------+-----------+-----------+-------+ | 500002 | 500002 | 200001 | 1001 | +----------+-----------+-----------+-------+ 1 row in setQuery
TABLET_ID,OBJECT_ID, andLS_IDvalues of a partitioned tableYou need to specify only the partition name for the query. Here is an example:
Assume that partitioned table
TBL1_LOG_Rexists in theoracle_tenanttenant. A sample query is as follows:obclient [SYS]> CREATE TABLE tbl1_log_r(log_id INT,log_date DATE NOT NULL DEFAULT SYSDATE) PARTITION BY RANGE(log_date) (PARTITION M202001 VALUES LESS THAN(TO_DATE('2020/02/01','YYYY/MM/DD')) , PARTITION M202002 VALUES LESS THAN(TO_DATE('2020/03/01','YYYY/MM/DD')) , PARTITION M202003 VALUES LESS THAN(TO_DATE('2020/04/01','YYYY/MM/DD')) , PARTITION M202004 VALUES LESS THAN(TO_DATE('2020/05/01','YYYY/MM/DD')) , PARTITION M202005 VALUES LESS THAN(TO_DATE('2020/06/01','YYYY/MM/DD')) , PARTITION M202006 VALUES LESS THAN(TO_DATE('2020/07/01','YYYY/MM/DD')) , PARTITION M202007 VALUES LESS THAN(TO_DATE('2020/08/01','YYYY/MM/DD')) , PARTITION M202008 VALUES LESS THAN(TO_DATE('2020/09/01','YYYY/MM/DD')) , PARTITION M202009 VALUES LESS THAN(TO_DATE('2020/10/01','YYYY/MM/DD')) , PARTITION M202010 VALUES LESS THAN(TO_DATE('2020/11/01','YYYY/MM/DD')) , PARTITION M202011 VALUES LESS THAN(TO_DATE('2020/12/01','YYYY/MM/DD')) , PARTITION M202012 VALUES LESS THAN(TO_DATE('2021/01/01','YYYY/MM/DD')) , PARTITION MMAX VALUES LESS THAN (MAXVALUE) );The following sample code queries related information about the
M202005partition in the partitioned table.obclient [SYS]> SELECT TABLE_ID AS TABLE_ID, OBJECT_ID, TABLET_ID, LS_ID FROM SYS.DBA_OB_TABLE_LOCATIONS WHERE DATABASE_NAME = 'SYS' AND TABLE_NAME= 'TBL1_LOG_R' AND PARTITION_NAME = 'M202005' AND ROWNUM = 1;The query result is as follows:
+----------+-----------+-----------+-------+ | TABLE_ID | OBJECT_ID | TABLET_ID | LS_ID | +----------+-----------+-----------+-------+ | 500003 | 500009 | 200006 | 1002 | +----------+-----------+-----------+-------+ 1 row in setQuery
TABLET_ID,OBJECT_ID, andLS_IDvalues of a subpartitioned tableYou need to specify both the partition and subpartition names for the query.
Assume that subpartitioned table
T2_F_RLexists in theoracle_tenanttenant. A sample query is as follows:obclient [SYS]> CREATE TABLE t2_f_rl(col1 INT,col2 VARCHAR2(50)) PARTITION BY RANGE(col1) SUBPARTITION BY LIST(col2) (PARTITION p0 VALUES LESS THAN(100) (SUBPARTITION sp0 VALUES('01'), SUBPARTITION sp1 VALUES('02') ), PARTITION p1 VALUES LESS THAN(200) (SUBPARTITION sp2 VALUES('01'), SUBPARTITION sp3 VALUES('02'), SUBPARTITION sp4 VALUES('03') ) );The following sample code queries related information about the
SP2subpartition in the subpartitioned table.obclient [SYS]> SELECT TABLE_ID AS TABLE_ID, OBJECT_ID, TABLET_ID, LS_ID FROM SYS.DBA_OB_TABLE_LOCATIONS WHERE DATABASE_NAME = 'SYS' AND TABLE_NAME= 'T2_F_RL' AND PARTITION_NAME = 'P1' AND SUBPARTITION_NAME = 'SP2' AND ROWNUM = 1;The query result is as follows:
+----------+-----------+-----------+-------+ | TABLE_ID | OBJECT_ID | TABLET_ID | LS_ID | +----------+-----------+-----------+-------+ | 500018 | 500023 | 200017 | 1003 | +----------+-----------+-----------+-------+ 1 row in set
Select the transfer destination.
Query the
DBA_OB_LSview to obtain the log stream status and information in the tenant.obclient [SYS]> SELECT * FROM SYS.DBA_OB_LS;The query result is as follows:
+-----------+-------+--------+--------------+---------------+-------------+---------------------+----------+---------------------+---------------------+------+ | TENANT_ID | LS_ID | STATUS | PRIMARY_ZONE | UNIT_GROUP_ID | LS_GROUP_ID | CREATE_SCN | DROP_SCN | SYNC_SCN | READABLE_SCN | FLAG | +-----------+-------+--------+--------------+---------------+-------------+---------------------+----------+---------------------+---------------------+------+ | 1006 | 1 | NORMAL | zone1 | 0 | 0 | NULL | NULL | 1701244663685197789 | 1701244663685197789 | | | 1006 | 1001 | NORMAL | zone1 | 1006 | 1001 | 1701239786827662637 | NULL | 1701244663685197789 | 1701244663685197789 | | | 1006 | 1002 | NORMAL | zone1 | 1007 | 1002 | 1701239786831568305 | NULL | 1701244664066906860 | 1701244664066906859 | | | 1006 | 1003 | NORMAL | zone1 | 1008 | 1003 | 1701239786834300282 | NULL | 1701244664175263949 | 1701244664175263948 | | +-----------+-------+--------+--------------+---------------+-------------+---------------------+----------+---------------------+---------------------+------+ 4 rows in setQuery the
DBA_OB_TABLET_TO_LSview to obtain the tablet distribution on log streams.obclient [SYS]> SELECT LS_ID, COUNT(*) AS C FROM SYS.DBA_OB_TABLET_TO_LS GROUP BY LS_ID;The query result is as follows:
+-------+------+ | LS_ID | C | +-------+------+ | 1 | 578 | | 1001 | 7 | | 1002 | 5 | | 1003 | 7 | +-------+------+ 4 rows in setSelect an appropriate log stream as the transfer destination based on the preceding information.
Execute the following statement to perform partition transfer:
ALTER SYSTEM TRANSFER PARTITION TABLE_ID [=] table_id, OBJECT_ID [=] object_id TO LS ls_id;where:
table_idindicates the ID of the table.object_idindicates the unique ID of the partition.ls_idindicates the ID of the destination log stream of the transfer.tenant_nameindicates the tenant to which the partition to be transferred belongs.
The following example shows how to transfer the
M202005partition of theTBL1_LOG_Rtable in theSYSdatabase of theoracle_tenanttenant from the current1002log stream to the1003log stream:obclient [SYS]> ALTER SYSTEM TRANSFER PARTITION TABLE_ID = 500003, OBJECT_ID = 500009 TO LS 1003;After the partition transfer command is executed successfully, you can check the task status by querying the following views.
Query the
DBA_OB_TRANSFER_PARTITION_TASKSview to obtain the values ofTASK_ID,TRANSFER_TASK_ID, andBALANCE_JOB_IDof the task.The
DBA_OB_TRANSFER_PARTITION_TASKSview displays the ongoing partition transfer tasks in the current tenant. A sample query is as follows:obclient [SYS]> SELECT TASK_ID, BALANCE_JOB_ID, TRANSFER_TASK_ID, STATUS FROM SYS.DBA_OB_TRANSFER_PARTITION_TASKS WHERE TABLE_ID = 500003 AND OBJECT_ID = 500009;A sample query result is as follows:
+---------+----------------+------------------+--------+ | TASK_ID | BALANCE_JOB_ID | TRANSFER_TASK_ID | STATUS | +---------+----------------+------------------+--------+ | 1 | 17304 | 1 | DOING | +---------+----------------+------------------+--------+ 1 row in setThe value of the
STATUSfield indicates the status of the task. Valid values:WAITING: The task is waiting to be scheduled.INIT: A load balancing job has been constructed for the task. You can view the execution progress of the load balancing job based on itsBALANCE_JOB_IDvalue.DOING: The task is in progress. You can view the task based onTRANSFER_TASK_ID, which will change several times. A partition transfer task involves multiple transfers.
If the query of the
DBA_OB_TRANSFER_PARTITION_TASKSview returns an empty result, you can query theDBA_OB_TRANSFER_PARTITION_TASK_HISTORYview to check the task result.Query the
DBA_OB_BALANCE_JOBSorDBA_OB_BALANCE_JOB_HISTORYview based on the obtainedBALANCE_JOB_IDvalue to check the execution status of the associated load balancing job.The
DBA_OB_BALANCE_JOBSview displays the load balancing jobs that are being performed in the tenant. Each tenant can have only one running load balancing job (BALANCE_JOB) at a time. A load balancing job generates multiple transfer tasks (TRANSFER_TASK). TheDBA_OB_BALANCE_JOB_HISTORYview displays the history of load balancing jobs that have been performed in the tenant. A sample query is as follows:obclient [SYS]> SELECT * FROM SYS.DBA_OB_BALANCE_JOBS WHERE JOB_ID = 17304;obclient [SYS]> SELECT * FROM SYS.DBA_OB_BALANCE_JOB_HISTORY WHERE JOB_ID = 17304;You must replace
17304with theBALANCE_JOB_IDvalue obtained in previous steps.The
STATUSfield in the query result indicates the execution status of the load balancing job. Valid values:DOING: The load balancing job is in progress.COMPLETED: The load balancing job was successfully executed.CANCELING: The load balancing job is being canceled.CANCELED: The load balancing job has been canceled.
Query the
DBA_OB_TRANSFER_TASKSorDBA_OB_TRANSFER_TASK_HISTORYview based on the obtainedTRANSFER_TASK_IDvalue and check the execution status of the associated transfer task.The
DBA_OB_TRANSFER_TASKSview displays the load balancing tasks that are being performed in the tenant. Multiple ongoing transfer tasks (TRANSFER_TASK) that belong to the same load balancing job (BALANCE_JOB) can exist concurrently in a tenant. TheDBA_OB_TRANSFER_TASK_HISTORYview displays the history of load balancing tasks that have been performed in the tenant. A sample query is as follows:obclient [SYS]> SELECT * FROM SYS.DBA_OB_TRANSFER_TASKS WHERE TASK_ID = 1;obclient [SYS]> SELECT * FROM SYS.DBA_OB_TRANSFER_TASK_HISTORY WHERE TASK_ID = 1;You must replace
1with theTRANSFER_TASK_IDvalue obtained in previous steps.The
STATUSfield in the query result indicates the execution status of the transfer task. Valid values:INIT: The task is being created.START: The task starts to be executed.DOING: The task is in progress.ABORTED: The task was aborted.COMPLETED: The task was successfully executed.FAILED: The task failed.CANCELED: The transfer task is canceled.
Query the
DBA_OB_TRANSFER_PARTITION_TASK_HISTORYview based on the obtainedTASK_IDvalue to confirm the result of the partition transfer task.The
DBA_OB_TRANSFER_PARTITION_TASK_HISTORYview displays the historical partition transfer tasks executed in the current tenant. A sample query is as follows:obclient [SYS]> SELECT * FROM SYS.DBA_OB_TRANSFER_PARTITION_TASK_HISTORY WHERE TASK_ID = 1;You must replace
1with theTASK_IDvalue obtained in previous steps.The
STATUSfield in the query result indicates the execution result of the partition transfer task. Valid values:COMPLETED: The task was successfully executed.FAILED: The task failed. You can view the cause of the failure in theCOMMENTcolumn. The following information is common in theCOMMENTfield:LS not exist or may be in DROPPING/WAIT_OFFLINE status: The destination log stream does not exist or is in theDROPPINGorWAITOFFLINEstate.LS status is not NORMAL or is in BLOCK_TABLET_IN state: The destination log stream is not in theNORMALstate. For example, it may be in theCREATINGorCREATEDstate, or the log stream is in theBLOCK_TABLET_INstate and cannot accept new partitions.Table has been dropped: The table of the partition to be transferred is deleted.Partition has been dropped: The partition to be transferred is deleted.Partition is already in dest LS: The partition is already on the transfer destination.Need retry, partition may be dropped: The partition is deleted when the transfer task is executed. The system will re-check whether the partition exists when generating the next load balancing task.Need retry, partition may be dropped or be transferred: The partition does not exist when the transfer task is executed. The partition may have been deleted or no longer exist on the source log stream. The system will re-check whether the partition exists when generating the next load balancing task.
After successful execution of the partition transfer task, query the information about the partition again.
obclient [SYS]> SELECT TABLE_ID AS TABLE_ID, OBJECT_ID, TABLET_ID, LS_ID FROM SYS.DBA_OB_TABLE_LOCATIONS WHERE DATABASE_NAME = 'SYS' AND TABLE_NAME= 'T2_F_RL' AND PARTITION_NAME = 'P1' AND SUBPARTITION_NAME = 'SP2' AND ROWNUM = 1;The query result is as follows:
+----------+-----------+-----------+-------+ | TABLE_ID | OBJECT_ID | TABLET_ID | LS_ID | +----------+-----------+-----------+-------+ | 500003 | 500009 | 200006 | 1003 | +----------+-----------+-----------+-------+ 1 row in setThe result shows that the
M202005partition of theTBL1_LOG_Rtable in theSYSdatabase has been transferred from log stream1002to log stream1003.