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
Situation Awareness
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

Troubleshooting Abnormal Connections and Active Connections

Updated on 2025-01-02 GMT+08:00

Description

When the number of database connections reaches the upper limit allowed for a DB instance, subsequent connections will be rejected. Abnormal changes in the number of connections and the number of active connections can indicate workload changes and database status to some extent.

RDS for PostgreSQL provides two related metrics:

  • Database connections: number of backend connections to a DB instance.
  • Active connections: number of active connections to a DB instance.

Cause Analysis

Connection pool parameter modification and workload change are considered as normal changes.

If you cannot determine whether there are normal changes or abruptly high concurrency, check database connection information.

  • The number of database connections suddenly decreases and then is restored to its normal range.

    Possible cause: Some connections are interrupted, or the DB instance reboots unexpectedly due to an OOM problem or crash.

  • The number of database connections increases suddenly or reaches the maximum.

    Possible cause: The number of new connections is greater than that of closed connections per unit time.

  • The concurrency is reduced and connections are not released in a timely manner if any of the following issues occurs:
    • There are slow SQL statements.
    • There are lock conflicts.
    • There are long-running transactions.

Troubleshooting

  • Query database connection information.

    You can sort out the database connection information using the information combination in the pg_stat_activity view.

    The following shows an example.

    -- Database connection information is filtered by database name, username, client IP address, and status and then sorted by the number of client connections in descending order.
    SELECT datname, usename, client_addr, state, count(*) AS client_number 
    FROM pg_stat_activity 
    WHERE state <> 'idle' 
    GROUP BY datname, usename, client_addr, state 
    ORDER BY client_number DESC;

    The preceding query result shows where the most connections come from. In this way, you can identify workload changes and high concurrency.

  • Check whether the maximum number of connections has been reached.

    If your instance cannot be connected and the following error logs are generated, the number of database connections reaches the upper limit.

    FATAL: remaining connection slots are reserved for non-replication superuser connections.
    FATAL: sorry, too many clients already.
  • Check for any abnormal reboot.
    1. Check the memory usage metric for any abnormal changes in memory usage.
    2. Download error logs of the corresponding time period by referring to Viewing and Downloading Error Logs.
    3. Use the keyword killed or the database system is in recovery mode to determine the time when the reboot occurred.
  • Slow SQL statements

    In most cases, slow SQL statements are accompanied by high CPU usage. You can locate slow SQL statements by referring to Troubleshooting High CPU Usage.

  • Lock conflicts
    1. Query the lock status of the current database connection using the pg_stat_activity view and the pg_blocking_pids function.
      -- Query the lock statuses of the earliest five PIDs (client connections) for the current transaction.
      SELECT pg_blocking_pids(pid), array_length(pg_blocking_pids(pid), 1) blocking_num, * 
      FROM pg_stat_activity 
      WHERE pid IN (select pid FROM pg_stat_activity WHERE state <> 'idel' 
      AND xact_start IS NOT NULL ORDER BY xact_start DESC LIMIT 5) 
      AND pid <> pg_backend_pid() 
      ORDER BY blocking_num DESC NULLS LAST;
    2. Based on the preceding query result, determine whether there are many lock conflicts that prevent the connections from being released.
  • Long-running transactions

    Locate long-running transactions by referring to Troubleshooting Long-Running Transactions.

Solution

  • Normal workload change or increased concurrency

    Upgrade the DB instance specifications.

  • Excessive database connections

    Temporary solution:

    1. Run SQL statements to release idle connections as user root.

      For example, to query the idle connection of the user user, run the following SQL statement to obtain the process ID:

      select * from pg_stat_activity where state = 'idle' and usename = 'user';

      Release the idle connection.

      select pg_terminate_backend(pid);

    2. Increase the value of max_connections and reboot your instance for the new value to be applied.

    Permanent solution:

    1. Reduce database connections.
    2. If database connections cannot be reduced, upgrade the instance specifications.
  • OOM exception or crash

    If the memory usage is high for a long time, upgrade the instance specifications or optimize the workloads to reduce the resident memory usage. If the DB instance reboots due to SQL statements, optimize the SQL statements.

  • Slow SQL statements

    Locate the slow SQL statements and optimize them.

  • Lock conflicts

    Check whether applications can be disconnected. If yes, use the pg_cancel_backend function to disconnect the applications from the database.

  • Long-running transactions

    Handle long-running transactions by referring to Troubleshooting Long-Running Transactions.

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