Configure SQL statement-level resource isolation

2025-12-09 07:09:36  Updated

You can bind the SQL statements that meet a specified condition to a specified resource group to implement SQL statement-level resource isolation. This topic describes how to configure SQL statement-level resource isolation in Oracle mode.

Prerequisites

  • Before you configure SQL statement-level resource isolation, we recommend that you learn about basic concepts such as resource group, resource management plan, and plan directive. For more information, see Overview of resource isolation.

  • The cgroup directory is configured and the cgroup feature is enabled. For more information, see Configure cgroups.

  • The user, database, table, and column for which resource isolation is to be implemented have been created.

Procedure

The following example shows how to bind different SQL conditions to the big_group and small_group resource groups, and control the CPU and IOPS resources available for different SQL statements by using the plan_a resource management plan.

  1. Log on to an Oracle tenant in the cluster as the administrator of the tenant.

  2. Call the CREATE_CONSUMER_GROUP subprogram in the DBMS_RESOURCE_MANAGER package to create two resource groups.

    obclient [SYS]> delimiter //
    
    obclient [SYS]> BEGIN DBMS_RESOURCE_MANAGER.CREATE_CONSUMER_GROUP(
    consumer_group => 'big_group' ,
    COMMENT => 'TP'
    );
    END; //
    
    obclient [SYS]> BEGIN DBMS_RESOURCE_MANAGER.CREATE_CONSUMER_GROUP(
    consumer_group => 'small_group' ,
    COMMENT => 'AP'
    );
    END; //
    

    Parameters:

    • CONSUMER_GROUP: the name of the resource group.

    • COMMENT: the comments on the resource group.

    You can query the DBA_RSRC_CONSUMER_GROUPS view to verify whether the resource groups are created. For more information about the DBA_RSRC_CONSUMER_GROUPS view, see DBA_RSRC_CONSUMER_GROUPS.

  3. Call the CREATE_PLAN subprogram in the DBMS_RESOURCE_MANAGER package to create a resource management plan.

    obclient [SYS]> BEGIN DBMS_RESOURCE_MANAGER.CREATE_PLAN(
    PLAN => 'plan_a');
    END; //
    

    Parameters:

    • PLAN: the name of the resource management plan.

    • COMMENT: the comments on the resource management plan.

    You can query the DBA_RSRC_PLANS view to verify whether the resource management plan is created. For more information about the DBA_RSRC_PLANS view, see DBA_RSRC_PLANS.

  4. Call the CREATE_PLAN_DIRECTIVE subprogram in the DBMS_RESOURCE_MANAGER package to create a plan directive for the resource management plan. When the resource management plan is enabled, the plan directive limits the CPU and IOPS resources available for the resource group.

    obclient [SYS]> BEGIN DBMS_RESOURCE_MANAGER.CREATE_PLAN_DIRECTIVE(
    PLAN => 'plan_a',
    GROUP_OR_SUBPLAN => 'big_group',
    COMMENT  => 'TP preferred',
    MGMT_P1 => 90,
    UTILIZATION_LIMIT =>60,
    MIN_IOPS => 20,
    MIX_IOPS => 100,
    WEIGHT_IOPS => 20);
    END; //
    
    obclient [SYS]> BEGIN DBMS_RESOURCE_MANAGER.CREATE_PLAN_DIRECTIVE(
    PLAN => 'plan_a',
    GROUP_OR_SUBPLAN => 'small_group' ,
    COMMENT  => 'AP preferred',
    MGMT_P1 => 100,
    UTILIZATION_LIMIT =>40,
    MIN_IOPS => 10,
    MIX_IOPS => 90,
    WEIGHT_IOPS => 30);
    END; //
    

    Parameters:

    • PLAN: the name of the resource management plan with which the plan directive is associated.

    • GROUP_OR_SUBPLAN: the resource group.

    • COMMENT: the comments on the plan directive. Default value: NULL.

    • MGMT_P1: the percentage of CPU resources available for the resource group when the system runs at full load. Default value: 100.

    • UTILIZATION_LIMIT: the upper limit on the CPU resources available for the resource group. The default value is 100. The value range is [0, 100]. The value 100 indicates that all CPU resources of the tenant are available for the resource group. The value 40 indicates that at most 40% of the CPU resources of the tenant are available for the resource group.

    • MIN_IOPS: the IOPS resources reserved for the resource group in the case of I/O resource contention. The sum of MIN_IOPS values of all resource groups cannot exceed 100. Default value: 0.

    • MAX_IOPS: the maximum IOPS resources available for the resource group. The sum of MAX_IOPS values of all resource groups can exceed 100. Default value: 100.

    • WEIGHT_IOPS: the weight for IOPS resources. The sum of WEIGHT_IOPS values of all resource groups can exceed 100. Default value: 0.

    You can query the DBA_RSRC_PLAN_DIRECTIVES or DBA_OB_RSRC_IO_DIRECTIVES view to verify whether the plan directive is created.

    For more information about the DBA_RSRC_PLAN_DIRECTIVES view, see DBA_RSRC_PLAN_DIRECTIVES.

    For more information about the DBA_OB_RSRC_IO_DIRECTIVES view, see DBA_OB_RSRC_IO_DIRECTIVES.

  5. Call the SET_CONSUMER_GROUP_MAPPING subprogram in the DBMS_RESOURCE_MANAGER package to create a matching rule for SQL statement-level resource isolation.

    obclient [SYS]> BEGIN DBMS_RESOURCE_MANAGER.SET_CONSUMER_GROUP_MAPPING(
    ATTRIBUTE => 'column',
    VALUE => 'sys.t.c3=3 for user_big',
    CONSUMER_GROUP => 'big_group');
    END; //
    
    obclient [SYS]> BEGIN DBMS_RESOURCE_MANAGER.SET_CONSUMER_GROUP_MAPPING(
    ATTRIBUTE => 'column',
    VALUE => 't.c3=5',
    CONSUMER_GROUP => 'small_group');
    END; //
    
    obclient [SYS]>delimiter ;
    

    Parameters:

    • ATTRIBUTE: the attribute type. The value column indicates SQL statement-level resource isolation. The value user indicates user-level resource isolation. The attribute name is case-insensitive.

    • VALUE: the attribute value, which includes the database name, table name, column name, constant value, and username.

      Notes:

      • The database name and username are optional. The default database name is the name of the current database, which is the same as the username. If no username is specified, the settings take effect for all users, including those created later in the current tenant.

      • The table name, column name, and constant value are required, and each of them can have only one value. The constant value must be a number or string.

      • When you specify the table name, column name, and username, the specified table, column, and user must exist.

      • In Oracle mode of OceanBase Database, the database name, table name, column name, and username will be automatically converted to uppercase after a statement is executed. You can enclose them with double quotation marks to prevent them from being converted to uppercase. Sample code:

        obclient [SYS]> BEGIN DBMS_RESOURCE_MANAGER.SET_CONSUMER_GROUP_MAPPING(
        ATTRIBUTE        =>  'column',
        VALUE            => '"test"."t1"."c3" = 3 for "user_big"',
        CONSUMER_GROUP   => 'big_group');
        END; //
        
    • CONSUMER_GROUP: the resource group to bind. When an SQL statement hits the matching rule specified by the VALUE parameter, this statement is bound to the specified resource group for execution. At present, an SQL statement can be bound to only one resource group.

    In this example, after the preceding matching rule for resource isolation is added, when the user_big user executes an SQL statement with a WHERE clause that contains sys.t.c3 = 3, this SQL statement will be bound to the resource group named big_group for execution.

    Notice

    An SQL statement can be bound to the big_group resource group provided that c3 is parsed into sys.t.c3 but the statement does not necessarily need to contain sys.t.. For example, the statement SELECT * FROM sys.t WHERE c3 = 1; will be bound to the big_group resource group.

    You can query the DBA_RSRC_GROUP_MAPPINGS view to verify whether the matching rule is created. For more information about DBA_RSRC_GROUP_MAPPINGS, see DBA_RSRC_GROUP_MAPPINGS.

  6. Enable a proper resource management plan for a resource group.

    The resources available for a resource group vary based on the resource management plan. Therefore, you must enable a proper resource management plan for a resource group.

    obclient [SYS]> ALTER SYSTEM SET resource_manager_plan = 'plan_a';
    

    Note

    If resource usage does not need to be limited, you can execute the ALTER SYSTEM SET resource_manager_plan = ''; statement to disable all resource management plans.

Considerations

  • After a matching rule for resource isolation is added, if you delete the table and user and create them again, this matching rule still applies.

  • A matching rule for resource isolation does not take effect immediately after being added, but is expected to take effect within 10 seconds. The time may vary based on the actual environment.

  • SQL statement-level resource isolation has a higher priority than user-level resource isolation.

  • After a matching rule for resource isolation is added, it takes effect only in the SELECT, INSERT, UPDATE, and DELETE statements, and does not take effect in data definition language (DDL), data control language (DCL), or procedural language (PL) statements. It can take effect in prepared statements.

Impact on performance

The impact of SQL statement-level resource isolation on performance is caused by retries. In user-level resource isolation, the resource group used for executing an SQL statement is determined before the SQL statement is parsed. However, in SQL statement-level resource isolation, the resource group used for executing an SQL statement is determined when the SQL statement is parsed or hits the plan cache. If the system detects that the resource group being used is not the determined resource group, the system will perform a retry to use the resources in the resource group determined based on the matching rule to execute this SQL statement. The impact of SQL statement-level resource isolation falls into three cases:

  1. If an SQL statement does not hit any matching rule, SQL statement-level resource isolation has no impact on the performance.

  2. If an SQL statement hits a matching rule that specifies to use the big_group resource group, this SQL statement is executed by using resources in the big_group resource group. The next SQL statement is also preferentially executed by using resources in this resource group. When the system detects that the matching rule hit by another SQL statement is bound to a different resource group, it will perform a retry to use resources in the new resource group to execute this statement. To continuously execute a batch of SQL statements that are bound to the same resource group, you can use this strategy so that the system needs to retry only the first SQL statement. This reduces the number of retries and causes slight impact on the performance.

  3. If the expected resource group of each SQL statement is different from that of the previous statement, the system must retry for each SQL statement. This greatly affects the performance.

More information

Configure user-level resource isolation

Contact Us