Help Center/ GaussDB/ Centralized_8.x/ Best Practices/ Best Practices of SQL Queries
Updated on 2024-06-03 GMT+08:00

Best Practices of SQL Queries

Based on the SQL execution mechanism and a large number of practices, SQL statements can be optimized by following certain rules to enable the database to execute SQL statements more quickly and obtain correct results.

  • Replace UNION with UNION ALL.

    UNION eliminates duplicate rows while merging two result sets but UNION ALL merges the two result sets without deduplication. Therefore, replace UNION with UNION ALL if you are sure that the two result sets do not contain duplicate rows based on the service logic.

  • Add not null to the join columns.

    If there are many NULL values in the JOIN columns, you can add the filter criterion IS NOT NULL to filter data in advance to improve the JOIN efficiency.

  • Convert NOT IN to NOT EXISTS.

    Nested Loop Anti Join must be used to implement NOT IN, and Hash Anti Join is required for NOT EXISTS. If no NULL value exists in the JOIN columns, NOT IN is equivalent to NOT EXISTS. Therefore, if you are sure that no NULL value exists, you can convert NOT IN to NOT EXISTS to generate hash join and to improve the query performance.

    The statements for creating a foreign table are as follows:

    DROP SCHEMA IF EXISTS no_in_to_no_exists_test CASCADE;
    CREATE SCHEMA no_in_to_no_exists_test;
    SET CURRENT_SCHEMA=no_in_to_no_exists_test;
    CREATE TABLE t1(c1 int, c2 int, c3 int);
    CREATE TABLE t2(d1 int, d2 int NOT NULL, d3 int);

    The statement for implementing the query using NOT IN is as follows:

    SELECT * FROM t1 WHERE  c1 NOT IN (SELECT d2 FROM t2);

    The plan is as follows:

    gaussdb=# EXPLAIN SELECT * FROM t1 WHERE  c1 NOT IN (SELECT d2 FROM t2);
                                QUERY PLAN
    ------------------------------------------------------------------
     Nested Loop Anti Join  (cost=0.00..29749.02 rows=968 width=12)
       Join Filter: ((t1.c1 = t2.d2) OR (t1.c1 IS NULL))
       ->  Seq Scan on t1  (cost=0.00..29.45 rows=1945 width=12)
       ->  Materialize  (cost=0.00..39.17 rows=1945 width=4)
             ->  Seq Scan on t2  (cost=0.00..29.45 rows=1945 width=4)
    (5 rows)

    Because there is no null value in the t2.d2 column (the t2.d2 column is NOT NULL in the table definition), the query can be equivalently modified as follows:

    1
    SELECT * FROM t1 WHERE  NOT EXISTS (SELECT * FROM t2 WHERE t1.c1=t2.d2);
    

    The generated plan is as follows:

    gaussdb=# EXPLAIN SELECT * FROM t1 WHERE  NOT EXISTS (SELECT * FROM t2 WHERE t1.c1=t2.d2);
                                QUERY PLAN
    ------------------------------------------------------------------
     Hash Anti Join  (cost=53.76..99.14 rows=972 width=12)
       Hash Cond: (t1.c1 = t2.d2)
       ->  Seq Scan on t1  (cost=0.00..29.45 rows=1945 width=12)
       ->  Hash  (cost=29.45..29.45 rows=1945 width=4)
             ->  Seq Scan on t2  (cost=0.00..29.45 rows=1945 width=4)
    (5 rows)
  • Use hashagg.

    If the GROUP BY condition exists in the query statement, the generated plan may contain sorting operations, that is, the plan contains the GroupAgg+Sort operator. As a result, the performance is poor. You can set the GUC parameter work_mem to increase the available memory and generate a plan with HashAgg to avoid sorting operations and improve performance. For details about how to set work_mem, contact the administrator.

  • Replace functions with CASE statements.

    The GaussDB Kernel performance greatly deteriorates if a large number of functions are called. In this case, you can change the pushdown functions to CASE statements.

  • Do not use functions or expressions for indexes.

    Using functions or expressions for indexes will stop indexing and enable scanning on the full table.

  • Do not use operator (!=, <, or >), NULL, OR, or implicit parameter conversion in WHERE clauses.
  • Split complex SQL statements.

    You can split an SQL statement into several ones and save the execution result to a temporary table if the SQL statement is too complex to be tuned using the solutions above, including but not limited to the following scenarios:

    • The same subquery is involved in multiple SQL statements of a job and the subquery contains a large amount of data.
    • Incorrect plan cost causes a small hash bucket of subquery. For example, the actual number of rows is 10 million, but only 1000 rows are in hash bucket.
    • Functions such as substr and to_number cause incorrect measures for subqueries containing a large amount of data.
    • BROADCAST subqueries are performed on large tables in multi-DN environment.

For details about optimization, see Typical SQL Optimization Methods.