Creating and Managing Tablespaces
Context
The administrator can use tablespaces to control the layout of disks where a database is installed. The advantages are as follows:
- If the disk partition or tablespace initially allocated to the database is full and the space cannot be logically extended, you can create and use tablespaces in other partitions until the system 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 stored in a disk having stable performance and high computing speed, such as a solid-state 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.
- You can use tablespaces to limit the disk space of databases. If a tablespace shares a partition with other tablespaces, the tablespace will never occupy the space allocated to other tablespaces.
- You can use tablespaces to manage the disk space used to store database data. The database will switch to the read-only mode when the disk usage of the tablespace reaches 90%. Once the disk usage drops below 90%, the database will be restored to the read-write mode. The automatic disk check of the CM is enabled by default. If the function is disabled, contact the administrator to enable it.
- Each tablespace corresponds to a file system directory. Create a tablespace corresponding to /pg_location/mount1/path1 and specify the maximum available space to 500 GB.
1 2
-- Create a tablespace. gaussdb=# CREATE TABLESPACE ds_location1 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.
- 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 catalogs. The corresponding storage directory is the base directory in the global data directory.
- You are advised not to use user-defined tablespaces in scenarios such as HCS and Huawei Cloud.
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 HCS and 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.
- Create user jack.
1
gaussdb=# CREATE USER jack IDENTIFIED BY '********';
If the following information is displayed, the creation is successful:
1
CREATE ROLE
- Create a tablespace.
1
gaussdb=# CREATE TABLESPACE fastspace RELATIVE LOCATION 'my_tablespace/tablespace1';
If the following information is displayed, the creation is successful:
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.
- Grant the permission of accessing the fastspace tablespace to user jack as a database system administrator.
1
gaussdb=# GRANT CREATE ON TABLESPACE fastspace TO jack;
If the following information is displayed, the grant operation is successful:
1
GRANT
- Create user jack.
- 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: Create a table in a specified tablespace.
1
gaussdb=# CREATE TABLE foo(i int) TABLESPACE fastspace;
If the following information is displayed, the creation is successful:
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: Run SET default_tablespace to set the default tablespace and then create a table.
1 2 3 4 5 6
gaussdb=# SET default_tablespace = 'fastspace'; SET gaussdb=# 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.
- Method 1: Create a table in a specified tablespace.
- Query a tablespace.
- Method 1: Check the pg_tablespace system catalog. View all the tablespaces defined by the system and users.
1
gaussdb=# SELECT spcname FROM pg_tablespace;
- Method 2: Run the meta-command of the gsql program to query the tablespaces.
gaussdb=# \db
- Method 1: Check the pg_tablespace system catalog. View all the tablespaces defined by the system and users.
- Query the tablespace usage.
- Query the current usage of the tablespace.
1
gaussdb=# 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.
- Calculate the tablespace usage.
Tablespace usage = Value of PG_TABLESPACE_SIZE/Size of the disk where the tablespace resides
- Query the current usage of the tablespace.
- Modify a tablespace.
- Delete a tablespace and related data.
- Delete user jack.
1 2
gaussdb=# DROP USER jack CASCADE; DROP ROLE
- Delete tables foo and foo2.
1 2
gaussdb=# DROP TABLE foo; gaussdb=# DROP TABLE foo2;
If the following information is displayed, the operation is successful:
1
DROP TABLE
- Delete tablespace fspace.
1 2
gaussdb=# DROP TABLESPACE fspace; DROP TABLESPACE
Only the tablespace owner or system administrator can delete a tablespace.
- Delete user jack.
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot