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
On this page

Query Optimization Operators

Updated on 2023-03-17 GMT+08:00

This section describes the syntax for migrating Teradata query optimization operators. The migration syntax determines how the keywords and features are migrated.

Use the inToExists parameter to configure the migration from IN orNOT IN to EXISTS or NOT EXISTS.

This parameter defaults to FALSE. To enable the query optimization feature, this parameter must be set to TRUE.

IN and NOT IN Conversion

When being converted to GaussDB(DWS) SQL queries, Teradata queries containing the IN and NOT IN operators have been optimized, and IN and NOT IN have been converted to EXISTS and NOT EXISTS, respectively. The IN and NOT IN operators support single or multiple columns. DSC will migrate the IN or NOT IN statement only when it exists in the WHERE or ON clause. The following example shows the conversion from IN to EXISTS, which is also applicable to the conversion from NOT IN to NOT EXISTS.

Simple conversion from IN to EXISTS

In the following example, the keyword IN is provided in the input file. During the migration, DSC replaces IN with EXISTS to optimize query performance.

NOTE:
  • The IN and NOT IN statements with nested IN and NOT IN keywords cannot be migrated. In this case, the scripts will be invalid after migration.
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    UPDATE tab1
       SET b = 123
     WHERE b IN ('abc') 
       AND b IN ( SELECT  i 
                    FROM tab2 
                    WHERE j NOT IN (SELECT m 
                                     FROM tab3
                                   )
                 )
    ;
    

    When an IN or NOT IN statement containing subqueries is being migrated, comments between the IN or NOT IN operator and the subqueries (see the example) cannot be migrated.

    Example:

    1
    2
    3
    4
    5
    6
    7
    SELECT * 
      FROM categories 
     WHERE category_name
        IN --comment 
            ( SELECT category_name 
                FROM categories1 ) 
     ORDER BY category_name;
    
  • Migrating IN or NOT IN statements whose object names contain $ and #
    • DSC will not migrate the query if the TABLE name or TABLE ALIAS starts with $.
      1
      2
      3
      SELECT Customer_Name
        FROM Customer_t $A
       WHERE Customer_ID IN( SELECT Customer_ID FROM Customer_t );
      
    • If the COLUMN name starts with #, DSC may fail to migrate the query.
      1
      2
      3
      SELECT Customer_Name
        FROM Customer_t
       WHERE #Customer_ID IN( SELECT #Customer_ID FROM Customer_t );
      

Input: IN

1
2
3
4
SELECT ...
   FROM tab1 t
   WHERE t.col1 IN (SELECT icol1 FROM tab2 e)
 ORDER BY col1

Output

1
2
3
4
5
6
7
SELECT ...
   FROM tab1 t
   WHERE EXISTS (SELECT icol1
                    FROM tab2 e
                   WHERE icol1 = t.col1
                 )
 ORDER BY col1;

Input: IN with multiple columns and Aggregate functions

1
2
3
4
5
6
7
8
9
SELECT deptno, job_id, empno, salary, bonus
   FROM emp_t
  WHERE ( deptno, job_id, CAST(salary AS NUMBER(10,2))+CAST(bonus AS NUMBER(10,2)) ) 
                IN ( SELECT deptno, job_id, 
                      MAX(CAST(salary AS NUMBER(10,2))+CAST(bonus AS NUMBER(10,2)))
                        FROM emp_t 
                       WHERE hire_dt >= CAST( '20170101' AS DATE FORMAT 'YYYYMMDD' ) 
                       GROUP BY deptno, job_id )
    AND hire_dt IS NOT NULL;

Output

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
SELECT deptno, job_id, empno, salary, bonus
   FROM emp_t MAlias1
  WHERE EXISTS ( SELECT deptno, job_id, 
                            MAX(CAST(salary AS NUMBER(10,2))+CAST(bonus AS NUMBER(10,2)))
                      FROM emp_t 
                     WHERE hire_dt >= CAST( '20170101' AS DATE)
                           AND deptno  = MAlias1.deptno
                           AND job_id   = MAlias1.job_id
                     GROUP BY deptno, job_id 
                    HAVING MAX(CAST(salary AS NUMBER(10,2))+CAST(bonus AS NUMBER(10,2)))
                            = CAST(MAlias1.salary AS NUMBER(10,2))+CAST(MAlias1.bonus AS NUMBER(10,2)) )
    AND hire_dt IS NOT NULL;

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