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
Help Center/ GaussDB/ Developer Guide(Distributed_2.x)/ Importing Data/ Updating Data in a Table/ Updating and Inserting Data by Using the MERGE INTO Statement

Updating and Inserting Data by Using the MERGE INTO Statement

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

To add all or a large amount of data in a table to an existing table, you can run the MERGE INTO statement in GaussDB to merge the two tables so that data can be quickly added to the existing table.

The MERGE INTO statement matches data in a source table with that in a target table based on a join condition. If data matches, UPDATE will be executed on the target table. Otherwise, INSERT will be executed. This statement is a convenient way to combine multiple operations and avoids multiple INSERT or UPDATE statements.

Prerequisites

You have the INSERT and UPDATE permissions for the target table and the SELECT permission for the source table.

Procedure

  1. Create a source table named products and insert data.

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    openGauss=# CREATE TABLE products 
    ( product_id INTEGER, 
      product_name VARCHAR2(60), 
      category VARCHAR2(60) 
    );
    
    openGauss=# INSERT INTO products VALUES 
    (1502, 'olympus camera', 'electrncs'),
    (1601, 'lamaze', 'toys'),
    (1666, 'harry potter', 'toys'),
    (1700, 'wait interface', 'books'); 
    

  2. Create a target table named newproducts and insert data.

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    openGauss=# CREATE TABLE newproducts 
    ( product_id INTEGER, 
      product_name VARCHAR2(60), 
      category VARCHAR2(60) 
    ); 
    
    openGauss=# INSERT INTO newproducts VALUES 
    (1501, 'vivitar 35mm', 'electrncs'),
    (1502, 'olympus ', 'electrncs'),
    (1600, 'play gym', 'toys'),
    (1601, 'lamaze', 'toys'), 
    (1666, 'harry potter', 'dvd'); 
    

  3. Run the MERGE INTO statement to merge data in the source table products into the target table newproducts.

    1
    2
    3
    4
    5
    6
    7
    openGauss=# MERGE INTO newproducts np    
    USING products p    
    ON (np.product_id = p.product_id )    
    WHEN MATCHED THEN     
      UPDATE SET np.product_name = p.product_name, np.category = p.category 
    WHEN NOT MATCHED THEN     
      INSERT VALUES (p.product_id, p.product_name, p.category) ; 
    

    For details on parameters in the statement, see Table 1. For more information, see MERGE INTO.

    Table 1 Parameters in the MERGE INTO statement

    Parameter

    Description

    Example Value

    INTO clause

    Specifies a target table that is to be updated or has data to be inserted.

    • A table alias is supported.
    • The target table can be copied, but the copied table cannot contain columns (such as auto-increment columns) that contain volatile functions. If enable_stream_operator is set to off, the target replication table must contain a primary key or a column must meet the unique not null constraint.

    Value: newproducts np

    The table name is newproducts and the alias is np.

    USING clause

    Specifies a source table. A table alias is supported.

    If the target table is a replication table, the source table must also be a replication table.

    Value: products p

    The table name is products and the alias is p.

    ON clause

    Specifies a join condition between a target table and a source table.

    Columns in the join condition cannot be updated.

    Value: np.product_id = p.product_id

    The join condition is that the product_id column in the target table newproducts has equivalent values as the product_id column in the source table products.

    WHEN MATCHED clause

    Performs UPDATE if data in the source table matches that in the target table based on the condition.

    • Only one WHEN MATCHED clause can be specified.
    • The WHEN MATCHED clause can be omitted. If it is omitted, no operation will be performed on the rows that meet the condition in the ON clause.
    • Columns involved in the distribution key of the target table cannot be updated.

    Value: WHEN MATCHED THEN UPDATE SET np.product_name = p.product_name, np.category = p.category

    When the condition in the ON clause is met, the values of the product_name and category columns in the target table newproducts are replaced with the values in the corresponding columns in the source table products.

    WHEN NOT MATCHED clause

    Performs INSERT if data in the source table does not match that in the target table based on the condition.

    • Only one WHEN NOT MATCHED clause can be specified.
    • The WHEN NOT MATCHED clause can be omitted.
    • An INSERT clause can contain only one VALUES.

    • The WHEN MATCHED and WHEN NOT MATCHED clauses can be exchanged in sequence. One of them can be omitted, but they cannot be omitted at the same time.

    Value: WHEN NOT MATCHED THEN

    INSERT VALUES (p.product_id, p.product_name, p.category)

    Insert rows in the source table products that do not meet the condition in the ON clause into the target table products.

  4. Query the target table newproducts after the merge.

    1
    openGauss=# SELECT * FROM newproducts;
    

    The command output is as follows:

     product_id |  product_name  | category
    ------------+----------------+-----------
           1501 | vivitar 35mm   | electrncs
           1502 | olympus camera | electrncs
           1666 | harry potter   | toys
           1600 | play gym       | toys
           1601 | lamaze         | toys
           1700 | wait interface | books
    (6 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