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

Stream Operation Hints

Updated on 2024-10-14 GMT+08:00

Function

These hints specify a stream operation, which can be broadcast or redistribute. You can also directly specify a method to generate a gather plan.

Syntax

1
2
[no] broadcast|redistribute(table_list)
gather(REL|JOIN|ALL)

Parameter Description

  • broadcast and redistribute
    • no specifies that the specified hint will not be used for a stream operation.
    • table_list specifies the table on which a stream operation is to be performed or the tables to be joined. For details, see Parameter Description.
  • gather
    The gather hint can specify the following plan generation modes:
    • REL: Only the gather path based on the base table is generated, and then the remaining plan is executed on the CN.
    • JOIN: A join-based gather path is generated as much as possible and is added to the join subplan that can be pushed down (the join subplan does not contain the redistribution node), and the remaining plan is executed on the CN. For a join plan that requires node redistribution, such a join-based gather path cannot be generated. Instead, a base table-based gather path is generated.
      CAUTION:

      After Hint(JOIN) is specified, the plan expected by Hint(JOIN) cannot be generated if the distribution table and replication table are joined, because the optimizer has found a better plan for replacement.

    • ALL: The Gather Rel or Gather Join path is selected based on the optimal mode.

Example

Hint the query plan in Example as follows:

1
2
explain
select /*+ no redistribute(store_sales store_returns item store) leading(((store_sales store_returns item store) customer)) */ i_product_name product_name ...

In the original plan, the join result of store_sales, store_returns, item, and store is redistributed before it is joined with customer. After the hinting, the redistribution is disabled and the join order is retained. The optimized plan is as follows:

Specify the gather hint for a statement.

  1. Generate the gather plan /* + GATHER(REL)*/ based on the base table.
    openGauss=# explain select /*+ GATHER(REL)*/* from t1, t2, t3 where t1.c2 = t2.c2 and t2.c2 = t3.c2;
    QUERY PLAN
    -------------------------------------------------------------------------------
    Hash Join  (cost=3.29..5.08 rows=10 width=24)
    Hash Cond: (t1.c2 = t3.c2)
    ->  Hash Join  (cost=1.64..3.30 rows=10 width=16)
    Hash Cond: (t1.c2 = t2.c2)
    ->  Streaming (type: GATHER)  (cost=0.31..1.52 rows=10 width=8)
    Node/s: All datanodes
    ->  Seq Scan on t1  (cost=0.00..1.05 rows=10 width=8)
    ->  Hash  (cost=1.52..1.52 rows=10 width=8)
    ->  Streaming (type: GATHER)  (cost=0.31..1.52 rows=10 width=8)
    Node/s: All datanodes
    ->  Seq Scan on t2  (cost=0.00..1.05 rows=10 width=8)
    ->  Hash  (cost=1.52..1.52 rows=10 width=8)
    ->  Streaming (type: GATHER)  (cost=0.31..1.52 rows=10 width=8)
    Node/s: All datanodes
    ->  Seq Scan on t3  (cost=0.00..1.05 rows=10 width=8)
    (15 rows)
  2. Generate the join gather plan /*+ GATHER(REL)*/ that can be pushed down.
    openGauss=# explain select /*+ GATHER(JOIN)*/* from t1, t2, t3 where t1.c1 = t2.c1 and t2.c2 = t3.c2;
    QUERY PLAN
    ---------------------------------------------------------------------------
    Hash Join  (cost=2.76..4.48 rows=10 width=24)
    Hash Cond: (t2.c2 = t3.c2)
    ->  Streaming (type: GATHER)  (cost=1.43..2.70 rows=10 width=16)
    Node/s: All datanodes
    ->  Hash Join  (cost=1.11..2.23 rows=10 width=16)
    Hash Cond: (t1.c1 = t2.c1)
    ->  Seq Scan on t1  (cost=0.00..1.05 rows=10 width=8)
    ->  Hash  (cost=1.05..1.05 rows=10 width=8)
    ->  Seq Scan on t2  (cost=0.00..1.05 rows=10 width=8)
    ->  Hash  (cost=1.52..1.52 rows=10 width=8)
    ->  Streaming (type: GATHER)  (cost=0.31..1.52 rows=10 width=8)
    Node/s: All datanodes
    ->  Seq Scan on t3  (cost=0.00..1.05 rows=10 width=8)
    (13 rows)
  3. Generate the gather plan /*+ GATHER(ALL)*/ based on the optimal mode.
    The GATHER(REL) or GATHER(JOIN) path is selected based on the optimal mode and rules.
    openGauss=# explain select /*+ GATHER(ALL)*/* from t1, t2, t3 where t1.c1 = t2.c1 and t2.c2 = t3.c2;
    QUERY PLAN
    ---------------------------------------------------------------------------
    Hash Join  (cost=2.76..4.48 rows=10 width=24)
    Hash Cond: (t2.c2 = t3.c2)
    ->  Streaming (type: GATHER)  (cost=1.43..2.70 rows=10 width=16)
    Node/s: All datanodes
    ->  Hash Join  (cost=1.11..2.23 rows=10 width=16)
    Hash Cond: (t1.c1 = t2.c1)
    ->  Seq Scan on t1  (cost=0.00..1.05 rows=10 width=8)
    ->  Hash  (cost=1.05..1.05 rows=10 width=8)
    ->  Seq Scan on t2  (cost=0.00..1.05 rows=10 width=8)
    ->  Hash  (cost=1.52..1.52 rows=10 width=8)
    ->  Streaming (type: GATHER)  (cost=0.31..1.52 rows=10 width=8)
    Node/s: All datanodes
    ->  Seq Scan on t3  (cost=0.00..1.05 rows=10 width=8)
    (13 rows)

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