Now, starting a new series of blog posts on Compression.
Beginning with BASIC Table Compression.
Basic Table Compression was introduced in 9i Release 2 (9.2.0). It is free with the Enterprise Edition. Basic Compression works only with Direct Path (Bulk Load) INSERTs. It does not apply to "normal" INSERT and UPDATE operations.
Basic Compression is actually "de-duplication". It identifies values that are repeated within the same database block and replaces them with tokens mapped to the list of values. Note the section that I have underlined. De-duplication does not span database blocks.
Here is a first demo of Basic Compression using INSERT /*+ APPEND */ (for Direct Path Insert).
I start with a table that is a multiplied copy of DBA_OBJECTS, named as SOURCE_DATA.
I then create table to hold compressed data. Note (let me repeat again : Basic Compression works only with DIRECT PATH INSERT).
So, a 49MB table is compressed down to 12MB. What if I UPDATE these rows ?
Updating only a single column without changing the length of the data in that column has increased the size of the table.
Let me continue the UPDATE experiment further, without increasing the length of data in any columns.
No further degradation ? (unless my UPDATE expands the size of data in one or more column(s)).
Note a difference between the two tables :
The Compressed table is created withPCT_FREE=10. PCT_FREE=0 (Note that this can also have an impact when you issue UPDATEs subsequently, UPDATEs that increase the size of data in one or more columns).
UPDATE : In 12c the syntax for BASIC Compression is "ROW STORE COMPRESS BASIC". Simply specifying "COMPRESS" or "COMPRESS BASIC" is supported for backward compatibility.
.
.
.
Beginning with BASIC Table Compression.
Basic Table Compression was introduced in 9i Release 2 (9.2.0). It is free with the Enterprise Edition. Basic Compression works only with Direct Path (Bulk Load) INSERTs. It does not apply to "normal" INSERT and UPDATE operations.
Basic Compression is actually "de-duplication". It identifies values that are repeated within the same database block and replaces them with tokens mapped to the list of values. Note the section that I have underlined. De-duplication does not span database blocks.
Here is a first demo of Basic Compression using INSERT /*+ APPEND */ (for Direct Path Insert).
I start with a table that is a multiplied copy of DBA_OBJECTS, named as SOURCE_DATA.
PDB1@ORCL> show user USER is "HEMANT" PDB1@ORCL> select count(*) from source_data; COUNT(*) ---------- 364496 PDB1@ORCL> PDB1@ORCL> select tablespace_name, segment_type, bytes/1048576 2 from user_segments 3 where segment_name = 'SOURCE_DATA'; TABLESPACE_NAME SEGMENT_TYPE BYTES/1048576 ------------------------------ ------------------ ------------- HEMANT TABLE 49 PDB1@ORCL>
I then create table to hold compressed data. Note (let me repeat again : Basic Compression works only with DIRECT PATH INSERT).
PDB1@ORCL> create table compressed_1 tablespace hemant compress as select * from source_data where 1=2; Table created. PDB1@ORCL> insert /*+ APPEND */ into compressed_1 2 select * from source_data; 364496 rows created. PDB1@ORCL> commit; Commit complete. PDB1@ORCL> PDB1@ORCL> col segment_name format a30 PDB1@ORCL> select segment_name, segment_type, bytes/1048576 2 from user_Segments 3 where tablespace_name = 'HEMANT'; SEGMENT_NAME SEGMENT_TYPE BYTES/1048576 ------------------------------ ------------------ ------------- COMPRESSED_1 TABLE 12 SOURCE_DATA TABLE 49 PDB1@ORCL>
So, a 49MB table is compressed down to 12MB. What if I UPDATE these rows ?
PDB1@ORCL> update compressed_1 2 set owner = owner; 364496 rows updated. PDB1@ORCL> commit; Commit complete. PDB1@ORCL> select segment_name, segment_type, bytes/1048576 2 from user_segments 3 where tablespace_name = 'HEMANT'; SEGMENT_NAME SEGMENT_TYPE BYTES/1048576 ------------------------------ ------------------ ------------- COMPRESSED_1 TABLE 22 SOURCE_DATA TABLE 49 PDB1@ORCL>
Updating only a single column without changing the length of the data in that column has increased the size of the table.
Let me continue the UPDATE experiment further, without increasing the length of data in any columns.
PDB1@ORCL> update compressed_1 2 set owner = owner, object_name = object_name, subobject_name = subobject_name, object_id = object_id, 3 data_object_id = data_object_id, object_type = object_type, created = created 4 / 364496 rows updated. PDB1@ORCL> commit; Commit complete. PDB1@ORCL> select segment_name, segment_type, bytes/1048576 2 from user_segments 3 where tablespace_name = 'HEMANT'; SEGMENT_NAME SEGMENT_TYPE BYTES/1048576 ------------------------------ ------------------ ------------- COMPRESSED_1 TABLE 22 SOURCE_DATA TABLE 49 PDB1@ORCL>
No further degradation ? (unless my UPDATE expands the size of data in one or more column(s)).
Note a difference between the two tables :
PDB1@ORCL> select table_name, compression, compress_for, pct_free 2 from user_tables; TABLE_NAME COMPRESS COMPRESS_FOR PCT_FREE ------------------------------ -------- ------------------------------ ---------- COMPRESSED_1 ENABLED BASIC 0 SOURCE_DATA DISABLED 10 PDB1@ORCL>
The Compressed table is created with
UPDATE : In 12c the syntax for BASIC Compression is "ROW STORE COMPRESS BASIC". Simply specifying "COMPRESS" or "COMPRESS BASIC" is supported for backward compatibility.
.
.
.
2 comments:
hello, a very usual side effect when you have several threads doing updates on compressed tables is the occurrence of dead locks, because of itl contention. Normally you solved this itl problems increasing the initrans parameter of the table , but with a compressed table the solution is uncompress the table.
Typo:
The Compressed table is created with PCT_FREE=0
Post a Comment