Compute
Elastic Cloud Server
Huawei Cloud Flexus
Bare Metal Server
Auto Scaling
Image Management Service
Dedicated Host
FunctionGraph
Cloud Phone Host
Huawei Cloud EulerOS
Networking
Virtual Private Cloud
Elastic IP
Elastic Load Balance
NAT Gateway
Direct Connect
Virtual Private Network
VPC Endpoint
Cloud Connect
Enterprise Router
Enterprise Switch
Global Accelerator
Management & Governance
Cloud Eye
Identity and Access Management
Cloud Trace Service
Resource Formation Service
Tag Management Service
Log Tank Service
Config
OneAccess
Resource Access Manager
Simple Message Notification
Application Performance Management
Application Operations Management
Organizations
Optimization Advisor
IAM Identity Center
Cloud Operations Center
Resource Governance Center
Migration
Server Migration Service
Object Storage Migration Service
Cloud Data Migration
Migration Center
Cloud Ecosystem
KooGallery
Partner Center
User Support
My Account
Billing Center
Cost Center
Resource Center
Enterprise Management
Service Tickets
HUAWEI CLOUD (International) FAQs
ICP Filing
Support Plans
My Credentials
Customer Operation Capabilities
Partner Support Plans
Professional Services
Analytics
MapReduce Service
Data Lake Insight
CloudTable Service
Cloud Search Service
Data Lake Visualization
Data Ingestion Service
GaussDB(DWS)
DataArts Studio
Data Lake Factory
DataArts Lake Formation
IoT
IoT Device Access
Others
Product Pricing Details
System Permissions
Console Quick Start
Common FAQs
Instructions for Associating with a HUAWEI CLOUD Partner
Message Center
Security & Compliance
Security Technologies and Applications
Web Application Firewall
Host Security Service
Cloud Firewall
SecMaster
Anti-DDoS Service
Data Encryption Workshop
Database Security Service
Cloud Bastion Host
Data Security Center
Cloud Certificate Manager
Edge Security
Managed Threat Detection
Blockchain
Blockchain Service
Web3 Node Engine Service
Media Services
Media Processing Center
Video On Demand
Live
SparkRTC
MetaStudio
Storage
Object Storage Service
Elastic Volume Service
Cloud Backup and Recovery
Storage Disaster Recovery Service
Scalable File Service Turbo
Scalable File Service
Volume Backup Service
Cloud Server Backup Service
Data Express Service
Dedicated Distributed Storage Service
Containers
Cloud Container Engine
SoftWare Repository for Container
Application Service Mesh
Ubiquitous Cloud Native Service
Cloud Container Instance
Databases
Relational Database Service
Document Database Service
Data Admin Service
Data Replication Service
GeminiDB
GaussDB
Distributed Database Middleware
Database and Application Migration UGO
TaurusDB
Middleware
Distributed Cache Service
API Gateway
Distributed Message Service for Kafka
Distributed Message Service for RabbitMQ
Distributed Message Service for RocketMQ
Cloud Service Engine
Multi-Site High Availability Service
EventGrid
Dedicated Cloud
Dedicated Computing Cluster
Business Applications
Workspace
ROMA Connect
Message & SMS
Domain Name Service
Edge Data Center Management
Meeting
AI
Face Recognition Service
Graph Engine Service
Content Moderation
Image Recognition
Optical Character Recognition
ModelArts
ImageSearch
Conversational Bot Service
Speech Interaction Service
Huawei HiLens
Video Intelligent Analysis Service
Developer Tools
SDK Developer Guide
API Request Signing Guide
Terraform
Koo Command Line Interface
Content Delivery & Edge Computing
Content Delivery Network
Intelligent EdgeFabric
CloudPond
Intelligent EdgeCloud
Solutions
SAP Cloud
High Performance Computing
Developer Services
ServiceStage
CodeArts
CodeArts PerfTest
CodeArts Req
CodeArts Pipeline
CodeArts Build
CodeArts Deploy
CodeArts Artifact
CodeArts TestPlan
CodeArts Check
CodeArts Repo
Cloud Application Engine
MacroVerse aPaaS
KooMessage
KooPhone
KooDrive

Outline Hints

Updated on 2024-08-20 GMT+08:00

Description

An outline is an important means of describing an execution plan and a persistent representation of plan fixing. An outline is stored in a database and needs to be compatible between versions. It can guide an optimizer to generate a specified plan. When generating an execution plan, the kernel can generate an outline. In addition, the optimizer can use the outline to control a plan. The outline is the core prerequisite capability of plan management.

Outline hints are generated by the optimizer to reproduce a plan. They start with BEGIN_OUTLINE_DATA and end with END_OUTLINE_DATA. You can obtain outline hints by using EXPLAIN(OUTLINE ON). The obtained outline hints can be used to control the plan.

Restrictions

  1. Ensure that set explain_perf_mode is set to pretty.
  2. An outline is used for planned reproduction and restoration. Currently, the outline can control the following aspects of the same SQL statement:
    • Query rewriting.
    • Physical operators of subquery at each layer:

      (a) Scanning mode

      (b) Joining method

      (c) Joining sequence

      (d) Index table for bitmap scan

      (e) Parameterized path

      (f) Materialization of joined inner tables

    • Aggregation method of subquery at each layer.
    • Additional processing for ANY sublink pullup: hashed or material.
    • Transmission mode of SMP data.
  3. Currently, bitmap scan and index scan hints of the kernel specify that the optimizer uses the specified index to generate the index scanning path when scanning related tables. The specific index conditions are generated by the optimizer based on the cost.
  4. For complex multi-table join SQL statements, the performance of outline fixed plan restoration is better than that of genetic algorithm.
  5. When there are outline hints, for hints that are not between BEGIN OUTLINE and END OUTLINE, if hints are generated by a control plan (hints mentioned in points 2, 3, and 4), they will become invalid. If hints are not generated by the control plan, they are retained, for example, hints of the slow SQL control rule wlmrule.

Syntax

Outline hints comply with the hint syntax.

BEGIN_OUTLINE_DATA
VERSION(@version_num)
END_OUTLINE_DATA

Parameters

  • @version_num: specifies an outline version. If not specified, the default value 1.0.0 is used. Currently, only 1.0.0 is supported, which is reserved for outline behavior control in later versions.
  • BEGIN_OUTLINE_DATA and END_OUTLINE_DATA: The generated outline hints must be placed between them.
NOTICE:
  1. BEGIN_OUTLINE_DATA and END_OUTLINE_DATA must be used in pairs.
  2. Only hints between BEGIN_OUTLINE_DATA and END_OUTLINE_DATA take effect.

Usage Guide

  1. Generate outline hints.

    Setting before use:

    SET explain_perf_mode = pretty;

    explain (Outline on):

    -- Create tables.
    gaussdb=# CREATE TABLE ot_t1(a int, b int);
    gaussdb=# CREATE TABLE ot_t2(a int, b int);
    
    -- Execute.
    gaussdb=# EXPLAIN (OUTLINE ON, COSTS OFF) SELECT * FROM ot_t1 JOIN ot_t2 ON ot_t1.a = ot_t2.a;
     id |          operation          
    ----+-----------------------------
      1 | ->  Hash Join (2,3)
      2 |    ->  Seq Scan on ot_t1
      3 |    ->  Hash
      4 |       ->  Seq Scan on ot_t2
    (4 rows)
    
     Predicate Information (identified by plan id) 
    -----------------------------------------------
       1 --Hash Join (2,3)
             Hash Cond: (ot_t1.a = ot_t2.a)
    (2 rows)
    
                        ====== Outline Data =====                    
    -----------------------------------------------------------------
       begin_outline_data
       HashJoin(@"sel$1" public.ot_t1@"sel$1" public.ot_t2@"sel$1")
       Leading(@"sel$1" (public.ot_t1@"sel$1" public.ot_t2@"sel$1"))
       TableScan(@"sel$1" public.ot_t1@"sel$1")
       TableScan(@"sel$1" public.ot_t2@"sel$1")
       version("1.0.0")
       end_outline_data
    (7 rows)
    NOTE:

    1. The preceding outline data consists of a series of hints. The hints and specified functions of query blocks in hints comply with the original hint capability.
    2. BEGIN_OUTLINE_DATA and END_OUTLINE_DATA indicate the start and end of the outline, respectively.
    3. HashJoin(@"sel$1" t1@"sel$1" t2@"sel$1") indicates that the hash join operation is performed on t1 (originally in the sel$1 query block) and t2 (originally in the sel$1 query block) in the first query block (only one query block). Leading(@"sel$1" (t1@"sel$1" t2@"sel$1")) indicates the join sequence. TableScan(@"sel$1" t1@"sel$1") and TableScan(@"sel$1" t2@"sel$1") indicate that sequential scans are performed on both t1 and t2.
    4. Outline can correspond to the plan.
    5. Currently, the version number is fixed at 1.0.0.
  2. Use outline hints.

    When the outline is used, the SQL statements converted from the outline are used.

    gaussdb=# EXPLAIN (OUTLINE ON, COSTS OFF) SELECT /*+ 
        BEGIN_OUTLINE_DATA
        HashJoin(@"sel$1" public.ot_t1@"sel$1" public.ot_t2@"sel$1")
        Leading(@"sel$1" (public.ot_t1@"sel$1" public.ot_t2@"sel$1"))
        TableScan(@"sel$1" public.ot_t1@"sel$1")
        TableScan(@"sel$1" public.ot_t2@"sel$1")
        VERSION("1.0.0")
        END_OUTLINE_DATA */ * FROM ot_t1 JOIN ot_t2 ON ot_t1.a = ot_t2.a;
     id |          operation          
    ----+-----------------------------
      1 | ->  Hash Join (2,3)
      2 |    ->  Seq Scan on ot_t1
      3 |    ->  Hash
      4 |       ->  Seq Scan on ot_t2
    (4 rows)
    
     Predicate Information (identified by plan id) 
    -----------------------------------------------
       1 --Hash Join (2,3)
             Hash Cond: (ot_t1.a = ot_t2.a)
    (2 rows)
    
                        ====== Outline Data =====                    
    -----------------------------------------------------------------
       begin_outline_data
       HashJoin(@"sel$1" public.ot_t1@"sel$1" public.ot_t2@"sel$1")
       Leading(@"sel$1" (public.ot_t1@"sel$1" public.ot_t2@"sel$1"))
       TableScan(@"sel$1" public.ot_t1@"sel$1")
       TableScan(@"sel$1" public.ot_t2@"sel$1")
       version("1.0.0")
       end_outline_data
    (7 rows)

    Compare 1 and 2. You can see that the two plans are the same, indicating that outline hints can be used to control the generation of plans.

  3. Compare plans with and without outline hints.
    1. Common hints:
      gaussdb=#  EXPLAIN (OUTLINE ON, COSTS OFF) SELECT /*+ 
          NestLoop(@"sel$1" ot_t1@"sel$1" ot_t2@"sel$1")
          Leading(@"sel$1" (ot_t1@"sel$1" ot_t2@"sel$1"))
          TableScan(@"sel$1" ot_t1@"sel$1")
          TableScan(@"sel$1" ot_t2@"sel$1") */ * FROM ot_t1 JOIN ot_t2 ON ot_t1.a = ot_t2.a;
       id |          operation          
      ----+-----------------------------
        1 | ->  Nested Loop (2,3)
        2 |    ->  Seq Scan on ot_t1
        3 |    ->  Materialize
        4 |       ->  Seq Scan on ot_t2
      (4 rows)
      
       Predicate Information (identified by plan id) 
      -----------------------------------------------
         1 --Nested Loop (2,3)
               Join Filter: (ot_t1.a = ot_t2.a)
      (2 rows)
      
                          ====== Outline Data =====                    
      -----------------------------------------------------------------
         begin_outline_data
         NestLoop(@"sel$1" public.ot_t1@"sel$1" public.ot_t2@"sel$1")
         Leading(@"sel$1" (public.ot_t1@"sel$1" public.ot_t2@"sel$1"))
         TableScan(@"sel$1" public.ot_t1@"sel$1")
         Materialize_Inner(@"sel$1" public.ot_t2@"sel$1")
         TableScan(@"sel$1" public.ot_t2@"sel$1")
         version("1.0.0")
         end_outline_data
      (8 rows)
       
    2. Outline hints:
      gaussdb=#  EXPLAIN (OUTLINE ON, COSTS OFF) SELECT /*+ 
          BEGIN_OUTLINE_DATA
          NestLoop(@"sel$1" ot_t1@"sel$1" ot_t2@"sel$1")
          Leading(@"sel$1" (ot_t1@"sel$1" ot_t2@"sel$1"))
          TableScan(@"sel$1" ot_t1@"sel$1")
          TableScan(@"sel$1" ot_t2@"sel$1")
          VERSION("1.0.0")
          END_OUTLINE_DATA */ * from ot_t1 join ot_t2 on ot_t1.a = ot_t2.a;
       id |        operation         
      ----+--------------------------
        1 | ->  Nested Loop (2,3)
        2 |    ->  Seq Scan on ot_t1
        3 |    ->  Seq Scan on ot_t2
      (3 rows)
      
       Predicate Information (identified by plan id) 
      -----------------------------------------------
         1 --Nested Loop (2,3)
               Join Filter: (ot_t1.a = ot_t2.a)
      (2 rows)
      
                          ====== Outline Data =====                    
      -----------------------------------------------------------------
         begin_outline_data
         NestLoop(@"sel$1" public.ot_t1@"sel$1" public.ot_t2@"sel$1")
         Leading(@"sel$1" (public.ot_t1@"sel$1" public.ot_t2@"sel$1"))
         TableScan(@"sel$1" public.ot_t1@"sel$1")
         TableScan(@"sel$1" public.ot_t2@"sel$1")
         version("1.0.0")
         end_outline_data
      (7 rows)
    NOTE:

    As you can see, common hints specify only part of the behavior and cannot completely fix the plan.

    In example a, common hints generate a materialize plan, which is not in the hints.

    In example b, outline hints do not generate the materialize plan and completely fix the plan.

We use cookies to improve our site and your experience. By continuing to browse our site you accept our cookie policy. Find out more

Feedback

Feedback

Feedback

0/500

Selected Content

Submit selected content with the feedback