PURGE
Description
The PURGE statement can be used to:
- Clear tables or indexes from the recycle bin and release all space related to the objects.
- Clear the recycle bin.
- Clear the objects of a specified tablespace in the recycle bin.
Precautions
-
The PURGE operation supports tables (PURGE TABLE), indexes (PURGE INDEX), and recycle bins (PURGE RECYCLEBIN).
-
The permission requirements for performing the PURGE operation are as follows:
- PURGE TABLE: The user must be the owner of the table and must have the USAGE permission on the schema to which the table belongs. When the separation of duties is disabled, system administrators have this permission by default.
- PURGE INDEX: The user must be the owner of the index and have the USAGE permission on the schema to which the index belongs. When the separation of duties is disabled, system administrators have this permission by default.
- PURGE RECYCLEBIN: Common users can clear only the objects owned by themselves in the recycle bin. In addition, the user must have the USAGE permission of the schema to which the objects belong. When the separation of duties is disabled, system administrators can clear all objects in the recycle bin by default.
Prerequisites
- The enable_recyclebin parameter has been enabled to enable the recycle bin. Contact the administrator for details about how to use the parameter.
- The recyclebin_retention_time parameter has been set for specifying the retention period of objects in the recycle bin. The objects will be automatically deleted after the retention period expires. Contact the administrator for details about how to use the parameter.
Syntax
PURGE { TABLE [schema_name.]table_name | INDEX index_name | RECYCLEBIN };
Parameters
- schema_name
Schema name
- TABLE [ schema_name. ] table_name
Clears a specified table in the recycle bin. The table can be schema-qualified.
- INDEX index_name
Clears a specified index in the recycle bin.
- RECYCLEBIN
Clears all objects in the recycle bin.
Examples
-- Create the reason_t1 table. gaussdb=# CREATE TABLE reason_t1( r_reason_sk integer, r_reason_id character(16), r_reason_desc character(100) ) WITH(STORAGE_TYPE = ustore); -- Create the reason_t2 table: gaussdb=# CREATE TABLE reason_t2( r_reason_sk integer, r_reason_id character(16), r_reason_desc character(100) ) WITH(STORAGE_TYPE = ustore); -- Add indexes to the reason_t1 and reason_t2 tables. gaussdb=# CREATE INDEX idx_t1 on reason_t1(r_reason_id); gaussdb=# CREATE INDEX idx_t2 on reason_t2(r_reason_id); gaussdb=# DROP TABLE reason_t1; gaussdb=# DROP TABLE reason_t2; -- View the recycle bin. gaussdb=# SELECT rcyname,rcyoriginname,rcytablespace FROM GS_RECYCLEBIN; rcyname | rcyoriginname | rcytablespace ----------------------------+---------------+--------------- BIN$31C94EB4207$8001$0==$0 | reason_t1 | 0 BIN$31C94EB420D$8001$0==$0 | idx_t1 | 0 BIN$31C94EB420A$8004$0==$0 | reason_t2 | 0 BIN$31C94EB420E$8004$0==$0 | idx_t2 | 0 (4 rows) -- Purge the table. gaussdb=# PURGE TABLE reason_t1; gaussdb=# SELECT rcyname,rcyoriginname,rcytablespace FROM GS_RECYCLEBIN; rcyname | rcyoriginname | rcytablespace ----------------------------+---------------+--------------- BIN$31C94EB420A$8004$0==$0 | reason_t2 | 0 BIN$31C94EB420E$8004$0==$0 | idx_t2 | 0 (2 rows) -- Purge the index. gaussdb=# PURGE INDEX idx_t2; gaussdb=# SELECT rcyname,rcyoriginname,rcytablespace FROM GS_RECYCLEBIN; rcyname | rcyoriginname | rcytablespace ----------------------------+---------------+--------------- BIN$31C94EB420A$8004$0==$0 | reason_t2 | 0 (1 row) -- Purge all objects in the recycle bin. gaussdb=# PURGE recyclebin; gaussdb=# SELECT rcyname,rcyoriginname,rcytablespace FROM GS_RECYCLEBIN; rcyname | rcyoriginname | rcytablespace -----------------------+---------------+--------------- (0 rows)
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