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 Database Age Increase Problem

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

Description

In a given database, the maximum age between the earliest and latest transactions is 2 billion (2^31). When the age of a table is greater than the value of autovacuum_freeze_max_age (400 million by default for an RDS for PostgreSQL instance), the autovacuum process freezes the table.

Once the database age exceeds 2 billion, the database breaks down and does not accept new transactions. You need to run VACUUM FULL in single-user mode to rectify the fault.

Cause Analysis

There are several possible causes:

  1. The autovacuum process does not work.
  2. Too much data is written to the database.
  3. Temporary tables are not released for a long time.
  4. There are read-only long-running transactions.
Figure 1 Cause analysis

Troubleshooting

  • The autovacuum process does not work.

    There are many dead tuples in the database, and the vacuum operation is not performed. Do as follows:

    1. Check whether the autovacuum parameter is set to on.
    2. Check the value of autovacuum_freeze_max_age. The default value is 400 million for an RDS for PostgreSQL instance. If you change the value to a value greater than 1 billion, you are advised to decrease the value.
    3. Check whether the conditions for triggering autovacuum are met.

      The autovacuum_vacuum_threshold parameter specifies the minimum number of updated or deleted tuples needed to trigger a VACUUM in any one table.

      The autovacuum_vacuum_scale_factor parameter specifies a fraction of the table size to add to autovacuum_vacuum_threshold when deciding whether to trigger a VACUUM.

    4. Run the following SQL statement to check whether the autovacuum process is normal:
      select * from pg_stat_activity where backend_type like '%vacuu%';
  • Too much data is written to the database.
    1. Check the database age.
      select datname, age(datfrozenxid) from pg_database where datname <> 'template1' and datname <> 'template0' order by age desc;
    2. Check whether the autovacuum parameters are properly set and compare them with those in the parameter template.
      SELECT name, setting FROM pg_settings WHERE name like '%vacuum%';
    3. Query the five oldest tables in the database.
      select relname, relfrozenxid,  age(relfrozenxid) aa from pg_class where relfrozenxid != 0 order by aa desc limit 5;
    4. Query the autovacuum status of these tables.
      SELECT schemaname, relname, last_vacuum, last_autovacuum, vacuum_count, autovacuum_count FROM pg_stat_all_tables WHERE relname='pg_toast_1335431529';
    5. Query the sizes of these tables.
      select pg_size_pretty(pg_relation_size(pg_toast_1335431536));
    6. Run the following command twice to check the value of heap_blks_scanned in the two execution results. If the value increases normally, autovacuum is running properly.
      select * from pg_stat_progress_vacuum;

      If autovacuum is running properly, check the disk read/write throughput and IOPS metrics in the last seven days. If the storage is fully occupied for a long period of time, the disk I/O is too high. Autovacuum process clearing cannot catch up with transaction ID generation and the database age increases.

      For details about the storage types and maximum throughput, see Performance Comparison of DB Instance Storage Types.

      Figure 2 Viewing disk read/write throughput
      Figure 3 Viewing IOPS
  • Temporary tables are not released for a long time.
    1. For details about the troubleshooting method, see 1 to 3. If the oldest table in the query result starts with tmp_%, check whether the table is a temporary table by viewing its properties.
    2. View the properties of the oldest table. If the value of the relpersistence field is t, the table is a temporary table.
      select * from pg_class where relname ='tmp_table_pu';
      NOTICE:

      In a database, temporary tables are not vacuumed, but their lifecycles are not long.

      Once the connection is released, the temporary tables are reclaimed.

      Therefore, you need to check whether there are persistent connections in the database by running the following statement:

      select (now()-backend_start) duration, *from pg_stat_activity  where backend_type = 'client backend' order by duration desc nulls  last;

      When any persistent connection is found, release it and then release the temporary table. Check whether the database age decreases.

  • There are long-running transactions.

    Long-running transactions are also a cause for database age increase. You can query long-running transactions of an RDS for PostgreSQL instance on the Cloud Eye console or using SQL statements.

    1. Run the following statement to check whether there are long-running transactions:
      select * from pg_stat_activity where state <> 'idle' order by xact_start;
    2. Alternatively, check the oldest active transaction duration on the Cloud Eye console and determine whether there are long-running transactions.
      NOTICE:

      You can only determine whether there are long-running transactions, but cannot view details about the long-running transactions on the Cloud Eye console. You are advised to use both SQL statements and Cloud Eye to identify long-running transactions.

      Figure 4 Viewing the oldest active transaction duration
    3. If there is a long-running transaction, run the following SQL statement to cancel the long-running transaction:
      -- Recommended:
      select pg_cancel_backend($PID);
      -- If the preceding statement is invalid, run the following statement:
      select pg_terminate_backend($PID);
    4. After canceling the long-running transaction, perform the vacuum operation on the oldest table in the database.
      vacuum "Test20231127";
    5. After the tablespace is cleared, run the following SQL statement for verification. If the value of n_dead_tup returns to 0 or is small, the restoration is complete.
      SELECT schemaname, relname, n_live_tup, n_dead_tup,
      FROM pg_stat_all_tables WHERE relname = 'Test20231127';

Solution

  • The autovacuum process does not work.
    1. Check whether the autovacuum parameter is set to on. If no, set it to on and observe the database age.
    2. Check the value of autovacuum_freeze_max_age. The default value is 400 million for an RDS for PostgreSQL instance. If you change the value to a value greater than 1 billion, decrease the value and observe the database age.
  • Too much data is written to the database.

    If the disk throughput reaches the performance upper limit, change the storage type.

    Run the VACUUM command to clear old tables.

  • Temporary tables are not released for a long time.

    Temporary tables will not be auto-vacuumed. If the database age increases due to temporary tables, release the client connection to reclaim the temporary tables.

  • There are long-running transactions.

    Cancel the long-running transactions and then run VACUUM on the oldest table in the database.

    1. Cancel the long-running transactions.
      select pg_cancel_backend($PID);
    2. Clear the table.
      vacuum table_name;

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