Quick Search:
 
 Oracle PL/SQL: Compressed Indexes Jump to:  
Category: >> Oracle PL/SQL >> Compressed Indexes  

<< lastnext >>

Snippet Name: Compressed Indexes

Description: Oracle introduced a compression option for indexes in Oracle 8.1. You can create an index as compressed, or rebuild it to compress it.

Index compression is implemented at the index block level. Oracle stores each distinct combination of compressed column values found within a specific index leaf block in a "Prefix" table within the leaf block and assigns each combination a unique prefix number.

The benefits of compression come from the fact that a properly compressed index uses a smaller number of leaf blocks - which tends to mean that less I/O is involved when the index is used, there is a reduced amount of buffer cache flushing, and the optimizer is likely to calculate a lower cost for using that index for range scans.

Also see:
» INDEXES: View table indexes
» INDEXES: Analyze Index
» INDEXES: Block Dump
» INDEXES: Rebuild Reverse
» INDEXES:
» INDEXES: ENABLE (function-based index)
» INDEXES: DISABLE (function-based index)
» INDEXES: Alter Index Parallel
» INDEXES: Alter Index Deallocate Unused
» INDEXES: Alter Index Allocate Extent
» INDEXES: Virtual / NoSegment
» INDEXES: Reverse Key Indexes
» INDEXES: Bitmap Join Indexes
» INDEXES: Bitmap Indexes
» INDEXES: Unique indexes
» INDEXES: Parallel Index
» INDEXES: Compute Statistics
» INDEXES: SORT and NOSORT
» INDEXES: Function-Based Index
» INDEXES: DROP index
» INDEXES: Alter index
» INDEXES: Single Column Non-unique
» INDEXES: Index Usage Notes
» Create INDEX

Comment: (none)

Language: PL/SQL
Highlight Mode: PLSQL
Last Modified: March 06th, 2009

CREATE INDEX <index_name>
 
ON (<first_column>, <second_column>)
PCTFREE <integer>
TABLESPACE <tablespace_name>
COMPRESS <integer *>;
 
* Must be AT LEAST 1 less than the NUMBER OF indexed columns
 
CREATE INDEX ix_pcodes
ON postal_code (state_abbrev, city_name, zip_code)
PCTFREE 0
TABLESPACE uwdata;
 
ANALYZE INDEX ix_pcodes VALIDATE STRUCTURE;
 
exec DBMS_STATS.gather_index_stats(USER, 'IX_PCODES');
 
SELECT opt_cmpr_count, opt_cmpr_pctsave
FROM index_stats;
 
SELECT SUM(bytes)
FROM user_segments
WHERE segment_name = 'IX_PCODES';
 
DROP INDEX ix_pcodes;
 
CREATE INDEX ix_pcodes
ON postal_code (state_abbrev, city_name, zip_code)
PCTFREE 0
TABLESPACE uwdata
COMPRESS 1;
 
ANALYZE INDEX ix_pcodes VALIDATE STRUCTURE;
 
exec DBMS_STATS.gather_index_stats(USER, 'IX_PCODES');
 
SELECT opt_cmpr_count, opt_cmpr_pctsave
FROM index_stats;
 
SELECT SUM(bytes)
FROM user_segments
WHERE segment_name = 'IX_PCODES';
 
DROP INDEX ix_pcodes;
 
CREATE INDEX ix_pcodes
ON postal_code (state_abbrev, city_name, zip_code)
PCTFREE 0
TABLESPACE uwdata
COMPRESS 2;
 
ANALYZE INDEX ix_pcodes VALIDATE STRUCTURE;
 
exec DBMS_STATS.gather_index_stats(USER, 'IX_PCODES');
 
SELECT opt_cmpr_count, opt_cmpr_pctsave
FROM index_stats;
 
SELECT SUM(bytes)
FROM user_segments
WHERE segment_name = 'IX_PCODES';
 
-- so pay attention to opt_comp_count


 
   Home |    Search |    Code Library |    Sponsors |    Privacy |    Terms of Use |    Contact Us © 2003 - 2024 psoug.org