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

Running SQL Statements

Updated on 2024-05-07 GMT+08:00

Running a Common SQL Statement

To enable an application to operate data in the database by running SQL statements (statements that do not need to transfer parameters), perform the following operations:

Operations such as SELECT, UPDATE, INSERT, and DELETE can be performed on XML data.

  1. Create a statement object by calling the createStatement method in Connection.

    1
    2
    3
    4
    5
    6
    // There will be security risks if the username and password used for authentication are directly written into code. It is recommended that the username and password be stored in the configuration file or environment variables (the password must be stored in ciphertext and decrypted when being used) to ensure security.
    // In this example, the username and password are stored in environment variables. Before running this example, set environment variables EXAMPLE_USERNAME_ENV and EXAMPLE_PASSWORD_ENV in the local environment (set the environment variable names based on the actual situation).
    String userName = System.getenv("EXAMPLE_USERNAME_ENV");
    String password = System.getenv("EXAMPLE_PASSWORD_ENV");
    Connection conn = DriverManager.getConnection("url",userName,password);
    Statement stmt = conn.createStatement();
    

  2. Run the SQL statement by calling the executeUpdate method in Statement.

    1
    int rc = stmt.executeUpdate("CREATE TABLE customer_t1(c_customer_sk INTEGER, c_customer_name VARCHAR(32));");
    
    NOTE:
    • If an execution request (not in a transaction block) received in the database contains multiple statements, the request is packed into a transaction. The VACUUM operation is not supported in a transaction block. If one of the statements fails, the entire request will be rolled back.
    • Use semicolons (;) to separate statements. Stored procedures, functions, and anonymous blocks do not support multi-statement execution. When preferQueryMode is set to simple, the statement does not execute the parsing logic, and the semicolons (;) cannot be used to separate statements in this scenario.
    • The slash (/) can be used as the terminator for creating a single stored procedure, function, anonymous block, or package body. When preferQueryMode is set to simple, the statement does not execute the parsing logic, and the slash (/) cannot be used as the terminator in this scenario.
    • When prepareThreshold is set to 1, each SQL statement executed by the statement is cached because cached statements are not evicted by default (default value of preferQueryMode). As a result, memory bloat may occur. In this case, set preferQueryMode to extendedCacheEverything to evict cached statements.

  3. Close the statement object.

    1
    stmt.close();
    

Running a Prepared SQL Statement

Prepared statements are complied and optimized once but can be used in different scenarios by assigning multiple values. Using prepared statements improves execution efficiency. If you want to run a statement for several times, use a precompiled statement. Perform the following operations:

  1. Create a prepared statement object by calling the prepareStatement method in Connection.

    1
    PreparedStatement pstmt = con.prepareStatement("UPDATE customer_t1 SET c_customer_name = ? WHERE c_customer_sk = 1");
    

  2. Set parameters by calling the setShort method in PreparedStatement.

    1
    pstmt.setShort(1, (short)2);
    
    CAUTION:

    After binding parameters are set in PrepareStatement, a B packet or U packet is constructed and sent to the server when the SQL statement is executed. However, the maximum length of a B packet or U packet cannot exceed 1023 MB. If the data bound at a time is too large, an exception may occur because the packet is too long. Therefore, when setting binding parameters in PrepareStatement, you need to evaluate and control the size of the bound data to avoid exceeding the upper limit of the packet.

  3. Run the prepared statement by calling the executeUpdate method in PreparedStatement.

    1
    int rowcount = pstmt.executeUpdate();
    

  4. Close the prepared statement object by calling the close method in PreparedStatement.

    1
    pstmt.close();
    

Calling a Stored Procedure

To call an existing stored procedure through JDBC in GaussDB, perform the following operations:

  1. Create a call statement object by calling the prepareCall method in Connection.

    1
    2
    3
    4
    5
    6
    // There will be security risks if the username and password used for authentication are directly written into code. It is recommended that the username and password be stored in the configuration file or environment variables (the password must be stored in ciphertext and decrypted when being used) to ensure security.
    // In this example, the username and password are stored in environment variables. Before running this example, set environment variables EXAMPLE_USERNAME_ENV and EXAMPLE_PASSWORD_ENV in the local environment (set the environment variable names based on the actual situation).
    String userName = System.getenv("EXAMPLE_USERNAME_ENV");
    String password = System.getenv("EXAMPLE_PASSWORD_ENV");
    Connection myConn = DriverManager.getConnection("url",userName,password);
    CallableStatement cstmt = myConn.prepareCall("{? = CALL TESTPROC(?,?,?)}");
    

  2. Set parameters by calling the setInt method in CallableStatement.

    1
    2
    3
    cstmt.setInt(2, 50); 
    cstmt.setInt(1, 20);
    cstmt.setInt(3, 90);
    

  3. Register an output parameter by calling the registerOutParameter method in CallableStatement.

    1
    cstmt.registerOutParameter(4, Types.INTEGER);  // Register an OUT parameter of the integer type.
    

  4. Call the stored procedure by calling the execute method in CallableStatement.

    1
    cstmt.execute();
    

  5. Obtain the output parameter by calling the getInt method in CallableStatement.

    1
    int out = cstmt.getInt(4);  // Obtain the OUT parameter.
    

    Example:

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    // The following stored procedure (containing the OUT parameter) has been created:
    create or replace procedure testproc 
    (
        psv_in1 in integer,
        psv_in2 in integer,
        psv_inout in out integer
    )
    as
    begin
        psv_inout := psv_in1 + psv_in2 + psv_inout;
    end;
    /
    

  6. Close the call statement by calling the close method in CallableStatement.

    1
    cstmt.close();
    
    NOTE:
    • Many database classes such as Connection, Statement, and ResultSet have a close() method. Close these classes after using their objects. Closing Connection will close all the related Statements, and closing a Statement will close its ResultSet.
    • Some JDBC drivers support named parameters, which can be used to set parameters by name rather than sequence. If a parameter has the default value, you do not need to specify any parameter value but can use the default value directly. Even though the parameter sequence changes during a stored procedure, the application does not need to be modified. Currently, the GaussDB JDBC driver does not support this method.
    • GaussDB does not support functions containing OUT parameters, or stored procedures and function parameters containing default values.
    • When you bind parameters in myConn.prepareCall("{? = CALL TESTPROC(?,?,?)}") during a stored procedure calling, you can bind parameters and register the first parameter as the output parameter according to the placeholder sequence or the fourth parameter as the output parameter according to the parameter sequence in the stored procedure. The preceding example registers the fourth parameter.
    NOTICE:
    • If JDBC is used to call a stored procedure whose returned value is a cursor, the returned cursor cannot be used.
    • A stored procedure and an SQL statement must be run separately.
    • Output parameters must be registered for parameters of the inout type in the stored procedure.

Calling a Stored Procedure When Overloading Is Enabled in Oracle-Compatible Mode

Set behavior_compat_options to 'proc_outparam_override', and then perform the following steps to call the stored procedure based on JDBC:

  1. Create a call statement object by calling the prepareCall method in Connection.

    1
    2
    3
    4
    5
    6
    // There will be security risks if the username and password used for authentication are directly written into code. It is recommended that the username and password be stored in the configuration file or environment variables (the password must be stored in ciphertext and decrypted when being used) to ensure security.
    // In this example, the username and password are stored in environment variables. Before running this example, set environment variables EXAMPLE_USERNAME_ENV and EXAMPLE_PASSWORD_ENV in the local environment (set the environment variable names based on the actual situation).
    String userName = System.getenv("EXAMPLE_USERNAME_ENV");
    String password = System.getenv("EXAMPLE_PASSWORD_ENV");
    Connection conn = DriverManager.getConnection("url",userName,password);
    CallableStatement cs = conn.prepareCall("{ CALL TEST_PROC(?,?,?) }");
    

  2. Set parameters by calling the setInt method in CallableStatement.

    1
    2
    3
    4
    PGobject pGobject = new PGobject();
    pGobject.setType("public.compfoo"); // Set the composite type name. The format is "schema.typename".
    pGobject.setValue("(1,demo)"); //: Bind the value of the composite type. The format is "(value1,value2)".
    cs.setObject(1, pGobject);
    

  3. Register an output parameter by calling the registerOutParameter method in CallableStatement.

    1
    2
    3
    4
    // Register an OUT parameter of the composite type. The format is "schema.typename".
    cs.registerOutParameter(2, Types.STRUCT, "public.compfoo");  
    // Register an OUT parameter of the table type. The format is "schema.typename".
    cs.registerOutParameter(3, Types.ARRAY, "public.compfoo_table");
    

  4. Call the stored procedure by calling the execute method in CallableStatement.

    1
    cs.execute();
    

  5. Obtain the output parameter by calling the getObject method in CallableStatement.

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    // The returned structure is of the user-defined type.
    PGobject result = (PGobject)cs.getObject(2);  // Obtain the out parameter.
    result.getValue(); // Obtain the string value of the composite type.
    result.getArrayValue(); // Obtain the array values of the composite type and sort the values according to the sequence of columns of the composite type.
    result.getStruct(); // Obtain the subtype names of the composite type and sort them according to the creation sequence.
    result.getAttributes(); // Return the object constructed from data in each column of the user-defined type. For the array and table types, PgArray is returned. For the user-defined type, PGobject is encapsulated. For other types of data, a character string is returned.
    // The returned result is of the table type.
    PgArray pgArray = (PgArray) cs.getObject(3);
    ResultSet rs = pgArray.getResultSet();
    while (rs.next()) {
      rs.getObject(2);// Object constructed from data in each row of the table type
    }
    
    NOTICE:

    If the table type of the output parameter is user-defined, for example, defined by running create type compfooTable is table of compfoo, the received return object is PgArray. In addition, the object obtained by rs.getObject(2) is also PgArray. In this case, the data of each column of the compfoo type cannot be obtained. To obtain the data, you must execute getPGobject() to obtain PgObject first.

  6. Close the call statement by calling the close method in CallableStatement.

    1
    cs.close();
    
    NOTE:
    • After the Oracle-compatible mode is enabled, you must use the {call proc_name(?,?,?)} format to call a stored procedure and use the {? = call func_name(?,?)} format to call a function. The question mark (?) on the left of the equal mark is the placeholder for the return value of the function and is used to register the return value of the function.
    • After behavior_compat_options is set to 'proc_outparam_override', the service needs to re-establish a connection. Otherwise, the stored procedures and functions cannot be correctly called.
    • If a function or stored procedure contains a composite type, bind and register parameters in the schema.typename format.

Example:
 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
16
17
18
19
20
// Create a composite data type in the database.
CREATE TYPE compfoo AS (f1 int, f3 text);
// The following stored procedure (containing the OUT parameter) has been created:
create or replace procedure test_proc
(
    psv_in in compfoo,
    psv_out out compfoo,
    table_out out compfoo_table
)
as
begin
    psv_out := psv_in;
    table_out:=compfoo_table();
    table_out.extend(2);
    table_out(1):=psv_out;
    table_out(2):=psv_out;
end;
/
// Create the table type in the database.
create type compfoo_table is table of compfoo;

Batch Processing

When a prepared statement processes multiple pieces of similar data, the database creates only one execution plan. This improves compilation and optimization efficiency. Perform the following operations:

  1. Create a prepared statement object by calling the prepareStatement method in Connection.

    1
    2
    3
    4
    5
    6
    // There will be security risks if the username and password used for authentication are directly written into code. It is recommended that the username and password be stored in the configuration file or environment variables (the password must be stored in ciphertext and decrypted when being used) to ensure security.
    // In this example, the username and password are stored in environment variables. Before running this example, set environment variables EXAMPLE_USERNAME_ENV and EXAMPLE_PASSWORD_ENV in the local environment (set the environment variable names based on the actual situation).
    String userName = System.getenv("EXAMPLE_USERNAME_ENV");
    String password = System.getenv("EXAMPLE_PASSWORD_ENV");
    Connection conn = DriverManager.getConnection("url",userName,password);
    PreparedStatement pstmt = conn.prepareStatement("INSERT INTO customer_t1 VALUES (?)");
    

  2. Call setShort to set parameters for each piece of data, and call addBatch to confirm that the setting is complete.

    1
    2
    pstmt.setShort(1, (short)2);
    pstmt.addBatch();
    

  3. Perform batch processing by calling the executeBatch method in PreparedStatement.

    1
    int[] rowcount = pstmt.executeBatch();
    

  4. Close the prepared statement object by calling the close method in PreparedStatement.

    1
    pstmt.close();
    
    NOTE:

    Do not terminate a batch processing action when it is ongoing; otherwise, database performance will deteriorate. Therefore, disable automatic commit during batch processing. Manually commit several rows at a time. The statement for disabling automatic commit is conn.setAutoCommit(false);.

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