TRUNCATE
is a SQL keyword that quickly deletes active rows from a table and the b-tree structures of its indexes. The active rows are deleted without dropping the table or its schema, access privileges, triggers, constraints, and other attributes.
1 Overview
The TRUNCATE
table statement quickly removes all rows from a table and all corresponding b-tree index data. The space formerly occupied by data rows and indexes becomes available for other tables, or can optionally reserve the space for reuse in subsequent operations on the same table or index partition.
TRUNCATE
is not equivalent to DROP TABLE. After TRUNCATE successfully executes, the specified table (and all its columns, and any synonyms, views, constraints, indexes, triggers, and access privileges) still exists in the database schema, but with no rows of data.
The TRUNCATE
statement works on tables that contain any type of columns, including smart large objects.
The table that you truncate can be a raw, temporary, or standard table, synonym (no view name). It can also be a virtual table, or a table with a virtual-index interface, provided that the virtual table or the virtual-index interface has a valid am_truncate() purpose function that was explicitly registered in the system catalog table.
The Dynamic Server automatically updates the statistics and distributions for the table and its indexes. It is not necessary to run the UPDATE STATISTICS statement immediately after committing the TRUNCATE statement.
Dynamic Server always logs the TRUNCATE operation, even for a non-logging database.
2 Syntax
>>-TRUNCATE [TABLE]-+--------+--+--------------+--+- table ---+--------> '- 'owner' --.-' '- synonym -' .- DROP STORAGE -. >--+----------------+------------------------------------------>> '- REUSE STORAGE '
3 Advantages
Removing rows with the TRUNCATE TABLE statement is faster than removing them with the DELETE statement. It performs the removal of all rows and of the B-tree structures of every index on the table as a single operation, and writes a single entry in the logical log when the transaction that includes TRUNCATE is committed or rolled back.
TRUNCATE
requires fewer updates to the system catalog than the equivalent DROP TABLE, CREATE TABLE, and any additional DDL statements to redefine any synonyms, views, constraints, triggers, privileges, fragmentation schemes, and other attributes and associated database objects of the table.
Remarks
If the table was fragmented, after the statement executes, each fragment has a space allocated for it that is the same size as that of the first extent size. The fragment size of any indexes also correspond to the size of the first extents.Before you run the TRUNCATE statement:
$ oncheck -pt demodb:customer2 TBLspace Report for demodb:informix.customer2 Physical Address 13:5577 Creation date 10/11/2017 04:20:27 TBLspace Flags 902 Row Locking TBLspace contains VARCHARS TBLspace use 4 bit bit-maps Maximum row size 227 Number of special columns 3 Number of keys 0 Number of extents 5 Current serial value 1 Current SERIAL8 value 1 Current BIGSERIAL value 1 Current REFID value 1 Pagesize (k) 2 First extent size 8 Next extent size 2048 Number of pages allocated 13371 Number of pages used 13164 Number of data pages 13160 Number of rows 150000 Partition partnum 13631734 Partition lockid 13631734 Extents Logical Page Physical Page Size Physical Pages 0 13:817888 736 736 736 13:818660 133 133 869 13:821583 5337 5337 6206 13:818915 117 117 6323 13:826920 7048 7048
After you run the TRUNCATE statement:
$ oncheck -pt demodb:customer2 TBLspace Report for demodb:informix.customer2 Physical Address 13:5577 Creation date 10/11/2017 04:20:27 TBLspace Flags 902 Row Locking TBLspace contains VARCHARS TBLspace use 4 bit bit-maps Maximum row size 227 Number of special columns 3 Number of keys 0 Number of extents 1 Current serial value 1 Current SERIAL8 value 1 Current BIGSERIAL value 1 Current REFID value 1 Pagesize (k) 2 First extent size 8 Next extent size 2048 Number of pages allocated 736 Number of pages used 1 Number of data pages 0 Number of rows 0 Partition partnum 13631734 Partition lockid 13631734 Extents Logical Page Physical Page Size Physical Pages 0 13:817888 736 736
Warning
The triggered action of any enabled trigger on table is ignored.CREATE TABLE wic_dual ( dummy varchar(1) default 'X' not null ); INSERT INTO wic_dual VALUES ('X'); CREATE TRIGGER wic_dual_del DELETE ON wic_dual REFERENCING OLD AS prv FOR EACH ROW WHEN (((SELECT COUNT(*) FROM wic_dual) = 0)) ( EXECUTE PROCEDURE wic_raise_msg(0, 'wic_dual_del: The [wic_dual] table must contain a single record.') );
delete from wic_dual where 1=1; #^ # 746: wic_dual_del: The [wic_dual] table must contain a single record. #
SELECT COUNT(*) FROM wic_dual; (count(*)) 1 TRUNCATE TABLE wic_dual; SELECT COUNT(*) FROM wic_dual; (count(*)) 0
4 Restrictions
- The table cannot be truncated if it has an open cursor or dirty readers.
- To truncate a table that has an R-tree, you must first drop the index. After truncate the table re-create the R-tree index.
- A view name can’t be use with truncate statement.
- The
TRUNCATE
statement does not automatically reset the serial value of a column. To reset the serial value of a column, you must do so explicitly, either before or after you run the TRUNCATE statement.
5 Examples
All following statements have the same effect, delete all rows and any related index data from the sales table:
TRUNCATE TABLE wic_user_soaplogs; TRUNCATE wic_user_soaplogs; TRUNCATE wic_user_soaplogs DROP STORAGE;
The following statement deletes all rows and any related index data from the sales table but prevent the space from being de-allocated::
TRUNCATE TABLE wic_user_soaplogs REUSE STORAGE;