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
Situation Awareness
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
Help Center/ TaurusDB/ Kernel/ Common Kernel Functions/ DISTINCT Optimization for Multi-Table Joins

DISTINCT Optimization for Multi-Table Joins

Updated on 2025-01-24 GMT+08:00

When using multi-table joins with DISTINCT, MySQL 8.0 needs to scan the table join results. When there is a large amount of data in base tables or when there are many table joins, a large amount of data needs to be scanned. As a result, the execution efficiency is low.

To improve DISTINCT query efficiency, particularly in the case of multi-table joins, TaurusDB adds the pruning function to the optimizer to remove unnecessary scanning branches.

Scenarios

  • Nested Loop Inner Join + Distinct
  • Nested Loop Outer Join + Distinct

Constraints

This feature is only available when the kernel version is 2.0.51.240300 or later.

Enabling DISTINCT Optimization for Multi-Table Joins

Table 1 Parameter description

Parameter

Level

Description

rds_nlj_distinct_optimize

Global, Session

Enables or disables DISTINCT optimization. The default value is OFF.

  • ON: DISTINCT optimization is enabled.
  • OFF: DISTINCT optimization is disabled.

You can also use hints to enable or disable DISTINCT optimization. The syntax is as follows:

  • Enabling DISTINCT optimization

    /*+ SET_VAR(rds_nlj_distinct_optimize=ON) */

  • Disabling DISTINCT optimization

    /*+ SET_VAR(rds_nlj_distinct_optimize=OFF) */

Example

  1. Use either of the following methods to enable DISTINCT optimization:
    • Run the SET command to set the switch value.
      mysql> SET rds_nlj_distinct_optimize=ON;
      Query OK, 0 rows affected (0.00 sec)
      
      mysql> SET rds_nlj_distinct_optimize=OFF;
      Query OK, 0 rows affected (0.00 sec)
    • Use hints to set the switch value in SQL statements.
      mysql> EXPLAIN ANALYZE SELECT/*+ SET_VAR(rds_nlj_distinct_optimize=ON) */ DISTINCT tt1.a FROM t1 AS tt1 JOIN t1 AS tt2 JOIN t1 AS tt3 ON tt2.a + 3 = tt3.a;
      
      mysql> EXPLAIN ANALYZE SELECT/*+ SET_VAR(rds_nlj_distinct_optimize=OFF) */ DISTINCT tt1.a FROM t1 AS tt1 JOIN t1 AS tt2 JOIN t1 AS tt3 ON tt2.a + 3 = tt3.a;
  2. Check the DISTINCT optimization effect in the multi-table join scenario.

    Run the Explain Analyze/Explain Format=tree statement to check whether the optimization is applied. If the execution plan contains keyword with distinct optimization, the optimization is applied.

    The detailed procedure is as follows:

    1. Prepare data.
      CREATE TABLE t1(a INT, KEY(a));
      INSERT INTO t1 VALUES(1),(2),(5),(6),(7),(8),(9),(11);
      ANALYZE TABLE t1;
    2. Disable the feature and run the following SQL statements. The optimizer chooses the default execution plan.
      mysql> SET rds_nlj_distinct_optimize=OFF;
      Query OK, 0 rows affected (0.00 sec)
      
      mysql> EXPLAIN FORMAT=TREE SELECT DISTINCT tt1.a FROM t1 AS tt1 LEFT JOIN t1 AS tt2 ON TRUE LEFT JOIN t1 AS tt3 ON tt2.a + 3 = tt3.a\G
      *************************** 1. row ***************************
      EXPLAIN: -> Table scan on <temporary>
          -> Temporary table with deduplication  (cost=29.18 rows=64)
              -> Nested loop left join  (cost=29.18 rows=64)
                  -> Left hash join (no condition)  (cost=6.78 rows=64)
                      -> Index scan on tt1 using a  (cost=1.05 rows=8)
                      -> Hash
                          -> Index scan on tt2 using a  (cost=0.13 rows=8)
                  -> Filter: ((tt2.a + 3) = tt3.a)  (cost=0.25 rows=1)
                      -> Index lookup on tt3 using a (a=(tt2.a + 3))  (cost=0.25 rows=1)
    3. Enable the feature and run the following SQL statements. The execution plan contains keyword with distinct optimization, which indicates that the optimization is applied.
      mysql> SET rds_nlj_distinct_optimize=ON;
      Query OK, 0 rows affected (0.00 sec)
      
      mysql> EXPLAIN FORMAT=TREE SELECT DISTINCT tt1.a FROM t1 AS tt1 LEFT JOIN t1 AS tt2 ON TRUE LEFT JOIN t1 AS tt3 ON tt2.a + 3 = tt3.a\G
      *************************** 1. row ***************************
      EXPLAIN: -> Table scan on <temporary>
          -> Temporary table with deduplication  (cost=29.18 rows=64)
              -> Nested loop left join with distinct optimization  (cost=29.18 rows=64)
                  -> Left hash join (no condition)  (cost=6.78 rows=64)
                      -> Index scan on tt1 using a  (cost=1.05 rows=8)
                      -> Hash
                          -> Index scan on tt2 using a  (cost=0.13 rows=8)
                  -> Filter: ((tt2.a + 3) = tt3.a)  (cost=0.25 rows=1)
                      -> Index lookup on tt3 using a (a=(tt2.a + 3))  (cost=0.25 rows=1)

Performance Test

TaurusDB completed the execution in 2.7s and scanned only about 610,000 rows of data. This is a significant improvement in execution efficiency compared to MySQL 8.0, which completed the execution in 186s and scanned 44 million rows of data.

In the following example, when performing a DISTINCT operation on the results after 7 tables were joined, MySQL 8.0.30 took 186s to execute and scanned about 44 million rows of data, while TaurusDB only took 2.7s and scanned about 610,000 rows of data.

Query statement:

select distinct ed.code,et.*
from ele_template et
left join ele_template_tenant ett on ett.template_id = et.id
left join ele_relation tm on tm.tom_id = et.id and tm.jerry_type = 'chapter'
left join ele_relation mv on mv.tom_id = tm.jerry_id and mv.jerry_type = 'variable'
left join ele_relation cv on cv.jerry_id = mv.jerry_id and cv.tom_type = 'column'
left join ele_doc_column edc on edc.id = cv.tom_id
left join ele_doc ed on ed.id = edc.doc_id
where ett.uctenantid = 'mmo0l3f8'
and ed.code = 'contract'
and et.billtype = 'contract'
order by ifnull(et.utime,et.ctime)
desc limit 0,10;

Execution plan:

+----+-------------+-------+------------+--------+-------------------------+-----------------+---------+----------------------+------+----------+----------------------------------------------+
| id | select_type | table | partitions | type   | possible_keys           | key             | key_len | ref                  | rows | filtered | Extra                                        |
+----+-------------+-------+------------+--------+-------------------------+-----------------+---------+----------------------+------+----------+----------------------------------------------+
|  1 | SIMPLE      | ed    | NULL       | ref    | PRIMARY,idx_code        | idx_code        | 203     | const                |    1 |   100.00 | Using index; Using temporary; Using filesort |
|  1 | SIMPLE      | ett   | NULL       | ref    | PRIMARY,idx_uctenanatid | idx_uctenanatid | 203     | const                |  352 |   100.00 | Using index                                  |
|  1 | SIMPLE      | et    | NULL       | eq_ref | PRIMARY,idx_billtype    | PRIMARY         | 8       | test.ett.template_id |    1 |    94.57 | Using where                                  |
|  1 | SIMPLE      | tm    | NULL       | ref    | idx_tom_id,idx_jerry_id | idx_tom_id      | 9       | test.ett.template_id |   59 |    10.00 | Using index condition; Using where; Distinct |
|  1 | SIMPLE      | mv    | NULL       | ref    | idx_tom_id,idx_jerry_id | idx_tom_id      | 9       | test.tm.jerry_id     |   59 |    10.00 | Using where; Distinct                        |
|  1 | SIMPLE      | cv    | NULL       | ref    | idx_tom_id,idx_jerry_id | idx_jerry_id    | 9       | test.mv.jerry_id     |   47 |    10.00 | Using where; Distinct                        |
|  1 | SIMPLE      | edc   | NULL       | eq_ref | PRIMARY,idx_doc_id      | PRIMARY         | 8       | test.cv.tom_id       |    1 |    50.00 | Using where; Distinct                        |
+----+-------------+-------+------------+--------+-------------------------+-----------------+---------+----------------------+------+----------+----------------------------------------------+
Figure 1 comparison of execution duration
Figure 2 comparison of scanned 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