هذه الصفحة غير متوفرة حاليًا بلغتك المحلية. نحن نعمل جاهدين على إضافة المزيد من اللغات. شاكرين تفهمك ودعمك المستمر لنا.

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
Help Center/ GaussDB(DWS)/ Best Practices/ Performance Tuning/ Analyzing SQL Statements That Are Being Executed to Handle GaussDB(DWS) Performance Issues

Analyzing SQL Statements That Are Being Executed to Handle GaussDB(DWS) Performance Issues

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

During development, developers often encounter problems such as excessive SQL connections, long SQL query time, and SQL query blocking. You can use the PG_STAT_ACTIVITY and PGXC_THREAD_WAIT_STATUS views to analyze and locate SQL problems. This section describes some common locating methods.

Table 1 Some PG_STAT_ACTIVITY fields

Name

Type

Description

usename

name

Name of the user logging in to the backend

client_addr

inet

IP address of the client connected to the backend null indicates either that the client is connected via a Unix socket on the server machine or that this is an internal process such as autovacuum.

application_name

text

Name of the application connected to the backend

state

text

Overall state of the backend. The value can be:

  • active: The backend is executing queries.
  • idle: The backend is waiting for new client commands.
  • idle in transaction: The backend is in a transaction, but there is no statement being executed in the transaction.
  • idle in transaction (aborted): The backend is in a transaction, but there are statements failed in the transaction.
  • fastpath function call: The backend is executing a fast-path function.
  • disabled: This state is reported if track_activities is disabled in this backend.
NOTE:

Common users can view only the session status of their own accounts. That is, the state information of other accounts is empty.

waiting

boolean

If the back end is currently waiting for a lock, the value is t. Otherwise, the value is f.

  • t stands for true.
  • f stands for false.

enqueue

text

Queuing status of a statement. Its value can be:

  • waiting in global queue: The statement is queuing in the global concurrency queue. The number of concurrent statements exceeds the value of max_active_statements configured for a single CN.
  • waiting in respool queue: The statement is queuing in the resource pool and the concurrency of simple jobs is limited. The main reason is that the concurrency of simple jobs exceeds the upper limit max_dop of the fast track.
  • waiting in ccn queue: The job is in the CCN queue, which may be global memory queuing, slow lane memory queuing, or concurrent queuing. The scenarios are:
    1. The available global memory exceeds the upper limit, the job is queuing in the global memory queue.
    2. Concurrent requests on the slow lane in the resource pool exceed the upper limit, which is specified by active_statements.
    3. The slow lane memory of the resource pool exceeds the upper limit, that is, the estimated memory of concurrent jobs in the resource pool exceeds the upper limit specified by mem_percent.
  • Empty or no waiting queue: The statement is running.

pid

bigint

ID of the backend thread.

Viewing Connection Information

  • Set track_activities to on.
    SET track_activities = on;

    The database collects the running information about active queries only if this parameter is set to on.

  • You can run the following SQL statements to check the current connection user, connection address, connection application, status, whether to wait for a lock, queuing status, and thread ID.
    1
    SELECT usename,client_addr,application_name,state,waiting,enqueue,pid FROM PG_STAT_ACTIVITY WHERE DATNAME='database name';
    

    The following command output is displayed:

    1
    2
    3
    4
    5
    6
     usename |  client_addr  | application_name | state  | waiting | enqueue |       pid       
    ---------+---------------+------------------+--------+---------+---------+-----------------
     leo     | 192.168.0.133 | gsql             | idle   | f       |         | 139666091022080
     dbadmin | 192.168.0.133 | gsql             | active | f       |         | 139666212681472
     joe     | 192.168.0.133 |                  | idle   | f       |         | 139665671489280
    (3 rows)
    
  • End a session (only the system administrator has the permission).
    1
    SELECT PG_TERMINATE_BACKEND(pid);
    

Viewing SQL Running Information

  • Run the following command to obtain all SQL information that the current user has permission to view (if the current user has administrator or preset role permission, all user query information can be displayed):
    1
    SELECT usename,state,query FROM PG_STAT_ACTIVITY WHERE DATNAME='database name';
    
    If the value of state is active, the query column indicates the SQL statement that is being executed. In other cases, the query column indicates the previous query statement. If the value of state is idle, the connection is idle and waits for the user to enter a command. The following command output is displayed:
    1
    2
    3
    4
    5
    6
     usename | state  |                                   query                                   
    ---------+--------+---------------------------------------------------------------------------
     leo     | idle   | select * from joe.mytable;
     dbadmin | active | SELECT usename,state,query FROM PG_STAT_ACTIVITY WHERE DATNAME='gaussdb';
     joe     | idle   | GRANT SELECT ON TABLE mytable to leo;
    (3 rows)
    
  • Run the following command to view the information about the SQL statements that are not in the idle state:
    1
    SELECT datname,usename,query FROM PG_STAT_ACTIVITY WHERE state != 'idle' ;
    

Viewing Time-Consuming Statements

  • Check the SQL statements that take a long time to execute.
    1
    SELECT current_timestamp - query_start as runtime, datname, usename, query FROM PG_STAT_ACTIVITY WHERE state != 'idle' order by 1 desc;
    

    Query statements are returned and sorted by execution time length in descending order. The first record is the query statement that takes the longest time to execute.

    1
    2
    3
    4
    5
         runtime     | datname  | usename |                                                                  query                                                                  
    -----------------+----------+---------+-----------------------------------------------------------------------------------------------------------------------------------------
     00:04:47.054958 | gaussdb  | leo     | insert into mytable1 select generate_series(1, 10000000);
     00:00:01.72789  | gaussdb  | dbadmin | SELECT current_timestamp - query_start as runtime, datname, usename, query FROM PG_STAT_ACTIVITY WHERE state != 'idle' order by 1 desc;
    (2 rows)
    
  • Alternatively, you can set current_timestamp - query_start to be greater than a threshold to identify query statements that are executed for a duration longer than this threshold.
    1
    SELECT query from PG_STAT_ACTIVITY WHERE current_timestamp - query_start > interval '2 days';
    

Querying Blocked Statements

  • Run the following command to view blocked query statements:
    1
    SELECT pid, datname, usename, state, query FROM PG_STAT_ACTIVITY WHERE state <> 'idle' and waiting=true;
    
    Run the following statement to end the blocked SQL session:
    1
    SELECT PG_TERMINATE_BACKEND(pid);
    
    NOTE:
    • In most cases, blocking is caused by internal locks and waiting=true is displayed. You can view the blocking in the pg_stat_activity view.
    • The blocked statements about file write and event schedulers cannot be viewed in the pg_stat_activity view.
  • View information about the blocked query statements, tables, and schemas.
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    SELECT w.query as waiting_query,
    w.pid as w_pid,
    w.usename as w_user,
    l.query as locking_query,
    l.pid as l_pid,
    l.usename as l_user,
    t.schemaname || '.' || t.relname as tablename
    from pg_stat_activity w join pg_locks l1 on w.pid = l1.pid
    and not l1.granted join pg_locks l2 on l1.relation = l2.relation
    and l2.granted join pg_stat_activity l on l2.pid = l.pid join pg_stat_user_tables t on l1.relation = t.relid
    where w.waiting;
    

    The command output includes a session ID, user information, query status, and table or schema that caused the block.

    After finding the blocked table or schema information, end the faulty session.

    1
    SELECT PG_TERMINATE_BACKEND(pid);
    

    If information similar to the following is displayed, the session is successfully terminated:

    PG_TERMINATE_BACKEND 
    ----------------------  
    t 
    (1 row)

    If information similar to the following is displayed, the user is attempting to terminate the session, but the session will be reconnected rather than terminated.

    FATAL:  terminating connection due to administrator command 
    FATAL:  terminating connection due to administrator command 
    The connection to the server was lost. Attempting reset: Succeeded.
    NOTE:

    If the PG_TERMINATE_BACKEND function is used by the gsql client to terminate the background threads of the session, the client will be reconnected automatically rather than be terminated.

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