Updated on 2024-06-07 GMT+08:00

Usage Guide

To use the advanced compression function, you must purchase a license. For details, contact Huawei technical support.

  1. Run the following command to enable the compression function:

    gaussdb=# ALTER DATABASE SET ilm = on;

    Check whether gsilmpolicy_seq and gsilmtask_seq exist in the public schema of the current database.

    gaussdb=# \d
                                                List of relations
     Schema |      Name       |   Type   |   Owner    |                       Storage                        
    --------+-----------------+----------+------------+------------------------------------------------------
     public | gsilmpolicy_seq | sequence | omm | 
     public | gsilmtask_seq   | sequence | omm | 

    or

    gaussdb=# SELECT a.oid, a.relname FROM pg_class a inner join pg_namespace b on a.relnamespace = b.oid
        WHERE (a.relname = 'gsilmpolicy_seq' OR a.relname = 'gsilmtask_seq') AND b.nspname = 'public';
    
      oid  |     relname     
    -------+-----------------
     17002 | gsilmpolicy_seq
     17004 | gsilmtask_seq
    (2 rows)

    If an exception occurs, a warning is reported.

    WARNING:  ILM sequences are already existed while initializing

  2. Add a compression policy for a table.

    • Create a table with a policy.
      gaussdb=# CREATE TABLE ilm_table_1 (col1 int, col2 text)
          ilm add policy row store compress advanced row
          after 3 days of no modification on (col1 < 1000);
    • Add a policy for an existing table.
      gaussdb=# CREATE TABLE ilm_table_2 (col1 int, col2 text);
      gaussdb=# ALTER TABLE ilm_table_2 ilm add policy row store
          compress advanced row after 3 days of no modification;
    • Check whether data is added to the policy view.
      gaussdb=# SELECT * FROM gs_my_ilmpolicies;
      
       policy_name |  policy_type  | tablespace | enabled | deleted 
      -------------+---------------+------------+---------+---------
       p1          | DATA MOVEMENT |            | YES     | NO
       p2          | DATA MOVEMENT |            | YES     | NO
      (2 rows)
    • Check whether the policy that meets the settings is added to the policy details view.
      gaussdb=# SELECT * FROM gs_my_ilmdatamovementpolicies;
      
       policy_name | action_type | scope | compression_level | tier_tablespace | tier_status |     condition_type     | condition_days | custom_function | policy_subtype | action_clause | tier_to 
      -------------+-------------+-------+-------------------+-----------------+-------------+------------------------+----------------+-----------------+----------------+---------------+---------
       p1          | COMPRESSION | ROW   | ADVANCED          |                 |             | LAST MODIFICATION TIME |              3 |                 |                |               | 
       p2          | COMPRESSION | ROW   | ADVANCED          |                 |             | LAST MODIFICATION TIME |              3 |                 |                |               | 
      (2 rows)
    • Check whether the policy corresponds to the target table.
      gaussdb=# SELECT * FROM gs_my_ilmobjects;
       policy_name | object_owner | object_name | subobject_name | object_type |    inherited_from    | tbs_inherited_from | enabled | deleted 
      -------------+--------------+-------------+----------------+-------------+----------------------+--------------------+---------+---------
       p1          | public       | ilm_table_1 |                | TABLE       | POLICY NOT INHERITED |                    | YES     | NO
       p2          | public       | ilm_table_2 |                | TABLE       | POLICY NOT INHERITED |                    | YES     | NO
      (2 rows)
      

  3. Perform compression evaluation.

    • Manually perform compression evaluation.

      To facilitate the test, the POLICY_TIME attribute is provided in the environment parameters of this function to determine whether the time unit is day or second. Run the following statement:

      gaussdb=# CALL DBE_ILM_ADMIN.CUSTOMIZE_ILM(11, 1);
      Insert random data for testing:
      gaussdb=# INSERT INTO ilm_table_1 select *, 'test_data' FROM generate_series(1, 10000);
      
      gaussdb=# DECLARE
          v_taskid number;
      gaussdb=# BEGIN
          DBE_ILM.EXECUTE_ILM(OWNER           => 'public',
                              OBJECT_NAME     => 'ilm_table_1',
                              TASK_ID         => v_taskid,
                              SUBOBJECT_NAME  => NULL,
                              POLICY_NAME     => 'ALL POLICIES',
                              EXECUTION_MODE  => 2);
          RAISE INFO 'Task ID is:%', v_taskid;
      gaussdb=# END;
      /
      If the input parameter is incorrect, an error message is displayed. If no error occurs, no information is displayed. (The RAISE INFO statement is added to the preceding code segment to print the ID of the current task.)
      INFO:  Task ID is:1
      Check the task information.
      gaussdb=# SELECT * FROM gs_my_ilmtasks;
      
      task_id | task_owner |   state   |         creation_time         |          start_time           |        completion_time        
      ---------+------------+-----------+-------------------------------+-------------------------------+-------------------------------
             1 | omm| COMPLETED | 2023-08-29 17:36:38.779555+08 | 2023-08-29 17:36:38.779555+08 | 2023-08-29 17:36:38.879485+08
      (1 row)
      Check the evaluation result.
      gaussdb=# SELECT * FROM gs_my_ilmevaluationdetails;
      
       task_id | policy_name | object_owner | object_name | subobject_name | object_type | selected_for_execution |      job_name     | comments 
      ---------+-------------+--------------+-------------+----------------+-------------+------------------------+-------------------+----------
             1 | p1          | public       | ilm_table_1 |                | TABLE       | SELECTED FOR EXECUTION | ilmjob$_postgres1 | 
      (1 row)
      Check the compression job information.
      gaussdb=# SELECT * FROM gs_my_ilmresults;
      
       task_id |     job_name      |       job_state        |          start_time           |        completion_time        | comments |               statistics               
      ---------+-------------------+------------------------+-------------------------------+-------------------------------+----------+----------------------------------------
             1 | ilmjob$_postgres1 | COMPLETED SUCCESSFULLY | 2023-08-29 17:36:38.779555+08 | 2023-08-29 17:36:38.879485+08 |          | SpaceSaving=0,BoundTime=0,LastBlkNum=0
      (1 row)
    • Trigger automatic scheduling evaluation in the background.

      Log in to the template1 database as the initial user and create a maintenance window.

      gaussdb=# 
      DECLARE
          V_HOUR INT := 22;
          V_MINUTE INT := 0;
          V_SECOND INT := 0;
          C_ADO_WINDOW_SCHEDULE_NAME TEXT := 'ado_window_schedule';
          C_ADO_WINDOW_PROGRAM_NAME TEXT := 'ado_window_program';
          C_MAINTENANCE_WINDOW_JOB_NAME TEXT := 'maintenance_window_job';
          V_MAINTENCE_WINDOW_REPEAT TEXT;
          V_MAINTENCE_WINDOW_START TIMESTAMPTZ;
          V_BE_SCHEDULE_ENABLE BOOL;
          V_MAINTENANCE_WINDOW_EXIST INT;
      BEGIN
          SELECT COUNT(*) INTO V_MAINTENANCE_WINDOW_EXIST FROM PG_CATALOG.PG_JOB WHERE JOB_NAME = 'maintenance_window_job' AND DBNAME = 'template1';
          IF CURRENT_DATABASE() != 'template1' THEN
              RAISE EXCEPTION 'Create maintenance_window FAILED, current database is not tempalte1';
          END IF;
          IF V_MAINTENANCE_WINDOW_EXIST = 0 AND CURRENT_DATABASE() = 'template1' THEN
              SELECT
                  CASE
                      WHEN NOW() < CURRENT_DATE + INTERVAL '22 HOUR' THEN CURRENT_DATE + INTERVAL '22 HOUR'
                      ELSE CURRENT_DATE + INTERVAL '1 DAY 22 HOUR'
                  END INTO V_MAINTENCE_WINDOW_START;
              --1. prepare for maintence window schedule
              SELECT 'freq=daily;interval=1;byhour='||V_HOUR||';byminute='||V_MINUTE||';bysecond='||V_SECOND INTO V_MAINTENCE_WINDOW_REPEAT;
              BEGIN
                  SELECT
                      CASE
                          WHEN VALUE = 1 THEN TRUE -- DBE_ILM_ADMIN.ILM_ENABLED
                          ELSE FALSE
                      END INTO V_BE_SCHEDULE_ENABLE
                      FROM PG_CATALOG.GS_ILM_PARAM WHERE IDX = 7; -- DBE_ILM_ADMIN.ENABLED
              EXCEPTION
                  WHEN OTHERS THEN
                      V_BE_SCHEDULE_ENABLE := FALSE;
              END;
              --2. Create ado window schedule
              DBE_SCHEDULER.CREATE_SCHEDULE(
                  SCHEDULE_NAME => C_ADO_WINDOW_SCHEDULE_NAME,
                  START_DATE => '9999-01-01 00:00:01',
                  REPEAT_INTERVAL => NULL,
                  END_DATE => NULL,
                  COMMENTS => 'ado window schedule');
              --3. Create ado window program
              DBE_SCHEDULER.CREATE_PROGRAM(
                  PROGRAM_NAME => C_ADO_WINDOW_PROGRAM_NAME,
                  PROGRAM_TYPE => 'plsql_block',
                  PROGRAM_ACTION => 'call prvt_ilm.be_execute_ilm(0);',
                  NUMBER_OF_ARGUMENTS => 0,
                  ENABLED => TRUE,
                  COMMENTS => NULL);
              --4. Create maintenance window master job
              DBE_SCHEDULER.CREATE_JOB(
                  JOB_NAME => C_MAINTENANCE_WINDOW_JOB_NAME,
                  START_DATE => V_MAINTENCE_WINDOW_START,
                  REPEAT_INTERVAL => V_MAINTENCE_WINDOW_REPEAT,
                  END_DATE => NULL,
                  JOB_TYPE => 'STORED_PROCEDURE'::TEXT,
                  JOB_ACTION => 'prvt_ilm.be_active_ado_window'::TEXT,
                  NUMBER_OF_ARGUMENTS => 0,
                  ENABLED => V_BE_SCHEDULE_ENABLE,
                  AUTO_DROP => FALSE,
                  COMMENTS => 'maintenance window job',
                  destination_name=> 'CCN');
          ELSE
              RAISE EXCEPTION 'CREATE ILM MAINTENANCE WINDOW FAILED';
          END IF;
      END;
      Automatic scheduling provides the following parameters for adjustment:
      gaussdb=# SELECT * FROM gs_adm_ilmparameters;
              name        | value 
      --------------------+-------
       EXECUTION_INTERVAL |    15
       RETENTION_TIME     |    30
       ENABLED            |     1
       POLICY_TIME        |     0
       ABS_JOBLIMIT       |    10
       JOB_SIZELIMIT      |   1024
       WIND_DURATION      |   240
       BLOCK_LIMITS       |    40
      (8 rows)
      • EXECUTION_INTERVAL: interval for executing the automatic scheduling task. By default, the task is executed every 15 minutes.
      • RETENTION_TIME: interval for deleting historical compression task records. By default, historical compression task records are deleted every 30 days.
      • ENABLED: specifies whether automatic scheduling is enabled. The default value is ENABLED.
      • POLICY_TIME: time unit for policy evaluation, which is used for tests. The default unit is day.
      • ABS_JOBLIMIT: indicates the maximum number of compression tasks generated in a single evaluation. The default value is 10.
      • JOB_SIZELIMIT: I/O upper limit of a single compression task. The default value is 1 GB.
      • WIND_DURATION: duration of a single maintenance window.
      • BLOCK_LIMITS: upper limit of the instance-level row-store compression rate. The default value is 40. The value ranges from 0 to 10000, in block/ms, indicating the maximum number of blocks that can be compressed per millisecond. 0 indicates that the rate is not limited. The maximum rate is calculated as follows: BLOCK_LIMITS x 1000 x BLOCKSIZE. For example, if the default value is 40, the maximum rate is 320,000 KB/s (40 x 1000 x 8 KB).

      The preceding parameters can be adjusted through the DBE_ILM_ADMIN.CUSTOMIZE_ILM() API.

      By default, the maintenance window is opened at 22:00 (Beijing time) every day. You can use the SET_ATTRIBUTE interface provided by the DBE_SCHEDULER to set the maintenance window.
      \c template1
       CALL DBE_ILM_ADMIN.DISABLE_ILM();
       CALL DBE_ILM_ADMIN.ENABLE_ILM();
      DECLARE
          newtime timestamptz := CLOCK_TIMESTAMP() + to_interval('2 seconds');
      BEGIN
          DBE_SCHEDULER.set_attribute(
              name          =>          'maintenance_window_job',
              attribute     =>          'start_date',
              value         =>          TO_CHAR(newtime, 'YYYY-MM-DD HH24:MI:SS')
          );
      END;
      /