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
On this page

Creating and Managing Tablespaces

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

Background

The administrator can use tablespaces to control the layout of disks where a database is installed. This has the following advantages:

  • If the initial disk partition or volume allocated to the database is full and the space cannot be logically increased, you can create and use tablespaces in other partitions until the space is reconfigured.
  • Tablespaces allow the administrator to distribute data based on the schema of database objects, improving system performance.
    • A frequently used index can be placed in a disk having stable performance and high computing speed, such as a solid device.
    • A table that stores archived data and is rarely used or has low performance requirements can be placed in a disk with a slow computing speed.
  • The administrator can use tablespaces to set the maximum available disk space. In this way, when a partition is shared with other data, tablespaces will not occupy excessive space in the partition.
  • You can use tablespaces to control the disk space occupied by data in a database. If the usage of a disk where a tablespace resides reaches 90%, the database switches to the read-only mode. It switches back to read/write mode when the disk usage becomes less than 90%.
    The automatic disk check of the cluster manager (CM) is enabled by default. To enable it, run the following command:
    gs_guc set -Z cmserver -N all -I all -c " enable_transaction_read_only = on "

    Restart the database to make the parameter settings take effect.

  • Each tablespace corresponds to a file system directory. Run the following command to create a tablespace corresponding to /pg_location/mount1/path1 and specify the maximum available space to 500 GB.
    1
    2
    -- Create a tablespace.
    openGauss=# CREATE TABLESPACE ds_location1 RELATIVE LOCATION '/pg_location/mount1/path1' MAXSIZE '500G';
    

    If MAXSIZE is used to manage tablespace quotas, the concurrent insertion performance may deteriorate by about 30%. MAXSIZE specifies the maximum quota for each each DN. The difference between the actual tablespace capacity of each DN and the specified quota should be within 500 MB. Determine whether to set a tablespace to its maximum size as required.

GaussDB provides two tablespaces: pg_default and pg_global.
  • Default tablespace pg_default: stores non-shared system catalogs, user tables, user table indexes, temporary tables, temporary table indexes, and internal temporary tables. The corresponding storage directory is the base directory in the instance data directory.
  • Shared tablespace pg_global: stores shared system tables. The corresponding storage directory is the base directory in the global data directory.
Precautions:
  • You are not advised to use user-defined tablespaces.

    This is because user-defined tablespaces are usually used with storage media other than the main storage (storage device where the default tablespace is located, such as a disk) to isolate I/O resources that can be used by different services. Storage devices use standard configurations and do not have other available storage media in scenarios such as Huawei Cloud. If the user-defined tablespace is not properly used, the system cannot run stably for a long time and the overall performance is affected. Therefore, you are advised to use the default tablespace.

Procedure

  • Create a tablespace.
    1. Run the following command to create user jack:
      1
      openGauss=# CREATE USER jack IDENTIFIED BY 'xxxxxxxxx';
      

      If the following information is displayed, the user has been created:

      1
      CREATE ROLE
      
    2. Run the following command to create a tablespace:
      1
      openGauss=# CREATE TABLESPACE fastspace RELATIVE LOCATION 'my_tablespace/tablespace1';
      

      If the following information is displayed, the tablespace has been created:

      1
      CREATE TABLESPACE
      

      fastspace is the new tablespace, and CN/DN data directory/pg_location/my_tablespace/tablespace1 is an empty directory on which users have read and write permissions.

    3. A database system administrator can run the following command to grant the permission of accessing the fastspace tablespace to user jack:
      1
      openGauss=# GRANT CREATE ON TABLESPACE fastspace TO jack;
      

      If the following information is displayed, the permission has been assigned:

      1
      GRANT
      
  • Create an object in a tablespace.

    If you have the CREATE permission on the tablespace, you can create database objects in the tablespace, such as tables and indexes.

    Take creating a table as an example:

    • Method 1: Run the following command to create a table in a specified tablespace:
      1
      openGauss=# CREATE TABLE foo(i int) TABLESPACE fastspace;
      

      If the following information is displayed, the table has been created:

      1
      2
      3
      NOTICE: The 'DISTRIBUTE BY' clause is not specified. Using 'i' as the distribution column by default.
      HINT: Please use 'DISTRIBUTE BY' clause to specify suitable data distribution column.
      CREATE TABLE
      
    • Method 2: Use set default_tablespace to set the default tablespace and then create a table:
      1
      2
      3
      4
      5
      6
      openGauss=# SET default_tablespace = 'fastspace';
      SET
      openGauss=# CREATE TABLE foo2(i int);
      NOTICE: The 'DISTRIBUTE BY' clause is not specified. Using 'i' as the distribution column by default.
      HINT: Please use 'DISTRIBUTE BY' clause to specify suitable data distribution column.
      CREATE TABLE
      

      In this example, fastspace is the default tablespace, and foo2 is the created table.

  • Use one of the following methods to query a tablespace:
    • Method 1: Check the pg_tablespace system catalog. Run the following command to view all the tablespaces defined by the system and users:
      1
      openGauss=# SELECT spcname FROM pg_tablespace;
      
    • Method 2: Run the following meta-command of the gsql program to query the tablespaces:
      openGauss=# \db
  • Query the tablespace usage.
    1. Query the current usage of the tablespace.
      1
      openGauss=# SELECT PG_TABLESPACE_SIZE('fastspace');
      

      Information similar to the following is displayed:

      1
      2
      3
      4
       pg_tablespace_size 
      --------------------
                  2146304
      (1 row)
      

      2146304 is the size of the tablespace, and its unit is byte.

    2. Calculate the tablespace usage.

      Tablespace usage = Value of PG_TABLESPACE_SIZE/Size of the disk where the tablespace resides

  • Modify a tablespace.
    Run the following command to rename tablespace fastspace to fspace:
    1
    2
    openGauss=# ALTER TABLESPACE fastspace RENAME TO fspace;
    ALTER TABLESPACE
    
  • Delete a tablespace and related data.
    • Run the following command to delete user jack:
      1
      2
      openGauss=# DROP USER jack CASCADE;
      DROP ROLE
      
    • Run the following commands to delete tables foo and foo2:
      1
      2
      openGauss=# DROP TABLE foo;
      openGauss=# DROP TABLE foo2;
      

      If the following information is displayed, the tables have been deleted:

      1
      DROP TABLE
      
    • Run the following command to delete tablespace fspace:
      1
      2
      openGauss=# DROP TABLESPACE fspace;
      DROP TABLESPACE
      
      NOTE:

      Only the tablespace owner or system administrator can delete a tablespace.

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