sys.column_store_segments (Transact-SQL)
TOC
Collapse the table of content
Expand the table of content

sys.column_store_segments (Transact-SQL)

 

Updated: June 10, 2016

THIS TOPIC APPLIES TO:yesSQL Server (starting with 2014)noAzure SQL DatabasenoAzure SQL Data Warehouse noParallel Data Warehouse

Contains a row for each column in a columnstore index.

Applies to: SQL Server (SQL Server 2012 through current version).
Column nameData typeDescription
partition_idbigintIndicates the partition ID. Is unique within a database.
hobt_idbigintID of the heap or B-tree index (hobt) for the table that has this columnstore index.
column_idintID of the columnstore column.
segment_idintID of the rowgroup. You can uniquely identify a segment using <hobt_id, partition_id, column_id>, <segment_id>.
versionintVersion of the column segment format.
encoding_typeintType of encoding used for that segment:

1 = VALUE_BASED - non-string/binary with no dictionary (very similar to 4 with some internal variations)

2 = VALUE_HASH_BASED - non-string/binary column with common values in dictionary

3 = STRING_HASH_BASED - string/binary column with common values in dictionary

4 = STORE_BY_VALUE_BASED - non-string/binary with no dictionary

5 = STRING_STORE_BY_VALUE_BASED - string/binary with no dictionary

All encodings take advantage of bit-packing and run-length encoding when possible.
row_countintNumber of rows in the row group.
has_nullsint1 if the column segment has null values.
base_idbigintBase value id if encoding type 1 is being used. If encoding type 1 is not being used, base_id is set to 1.
magnitudefloatMagnitude if encoding type 1 is being used. If encoding type 1 is not being used, magnitude is set to 1.
primary_dictionary_idintA value of 0 represents the global dictionary. A value of -1 indicates that there is no global dictionary created for this column.
secondary_dictionary_idintA non-zero value points to the local dictionary for this column in the current segment (i.e. the rowgroup). A value of -1 indicates that there is no local dictionary for this segment.
min_data_idbigintMinimum data id in the column segment.
max_data_idbigintMaximum data id in the column segment.
null_valuebigintValue used to represent nulls.
on_disk_sizebigintSize of segment in bytes.

The following query returns information about segments of a columnstore index.

SELECT i.name, p.object_id, p.index_id, i.type_desc,   
    COUNT(*) AS number_of_segments  
FROM sys.column_store_segments AS s   
INNER JOIN sys.partitions AS p   
    ON s.hobt_id = p.hobt_id   
INNER JOIN sys.indexes AS i   
    ON p.object_id = i.object_id  
WHERE i.type = 6  
GROUP BY i.name, p.object_id, p.index_id, i.type_desc ;  
GO  

All columns require at least VIEW DEFINITION permission on the table. The following columns return null unless the user also has SELECT permission: has_nulls, base_id, magnitude, min_data_id, max_data_id, and null_value.

The visibility of the metadata in catalog views is limited to securables that a user either owns or on which the user has been granted some permission. For more information, see Metadata Visibility Configuration.

Object Catalog Views (Transact-SQL)
Catalog Views (Transact-SQL)
Querying the SQL Server System Catalog FAQ
sys.columns (Transact-SQL)
sys.all_columns (Transact-SQL)
sys.computed_columns (Transact-SQL)
Columnstore Indexes Guide
sys.column_store_dictionaries (Transact-SQL)

Community Additions

ADD
Show:
© 2016 Microsoft