1
+ /*
2
+ Columnstore Indexes Scripts Library for SQL Server 2016:
3
+ Row Groups Details - Shows detailed information on the Columnstore Row Groups
4
+ Version: 1.0.3, November 2015
5
+
6
+ Copyright 2015 Niko Neugebauer, OH22 IS (http://www.nikoport.com/columnstore/), (http://www.oh22.is/)
7
+
8
+ Licensed under the Apache License, Version 2.0 (the "License");
9
+ you may not use this file except in compliance with the License.
10
+ You may obtain a copy of the License at
11
+
12
+ http://www.apache.org/licenses/LICENSE-2.0
13
+
14
+ Unless required by applicable law or agreed to in writing, software
15
+ distributed under the License is distributed on an "AS IS" BASIS,
16
+ WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
17
+ See the License for the specific language governing permissions and
18
+ limitations under the License.
19
+ */
20
+
21
+ declare @SQLServerVersion nvarchar (128 ) = cast (SERVERPROPERTY (' ProductVersion' ) as NVARCHAR (128 )),
22
+ @SQLServerEdition nvarchar (128 ) = cast (SERVERPROPERTY (' Edition' ) as NVARCHAR (128 ));
23
+ declare @errorMessage nvarchar (512 );
24
+
25
+ -- --Ensure that we are running SQL Server 2016
26
+ if substring (@SQLServerVersion,1 ,CHARINDEX (' .' ,@SQLServerVersion)- 1 ) <> N ' 13'
27
+ begin
28
+ set @errorMessage = (N ' You are not running a SQL Server 2016. Your SQL Server version is ' + @SQLServerVersion);
29
+ Throw 51000 , @errorMessage, 1 ;
30
+ end
31
+
32
+ if SERVERPROPERTY (' EngineEdition' ) <> 3
33
+ begin
34
+ set @errorMessage = (N ' Your SQL Server 2016 Edition is not an Enterprise or a Developer Edition: Your are running a ' + @SQLServerEdition);
35
+ Throw 51000 , @errorMessage, 1 ;
36
+ end
37
+
38
+ -- ------------------------------------------------------------------------------------------------------------------
39
+ if EXISTS (select * from sys .objects where type = ' p' and name = ' cstore_GetRowGroupsDetails' and schema_id = SCHEMA_ID (' dbo' ) )
40
+ Drop Procedure dbo .cstore_GetRowGroupsDetails ;
41
+ GO
42
+
43
+ create procedure dbo .cstore_GetRowGroupsDetails (
44
+ -- Params --
45
+ @schemaName nvarchar (256 ) = NULL , -- Allows to show data filtered down to the specified schema
46
+ @tableName nvarchar (256 ) = NULL , -- Allows to show data filtered down to the specified table name
47
+ @partitionNumber bigint = 0 , -- Allows to show details of each of the available partitions, where 0 stands for no filtering
48
+ @showTrimmedGroupsOnly bit = 0 , -- Filters only those Row Groups, which size <> 1048576
49
+ @showNonCompressedOnly bit = 0 , -- Filters out the comrpessed Row Groups
50
+ @showFragmentedGroupsOnly bit = 0 , -- Allows to show the Row Groups that have Deleted Rows in them
51
+ @minSizeInMB Decimal (16 ,3 ) = NULL , -- Minimum size in MB for a table to be included
52
+ @maxSizeInMB Decimal (16 ,3 ) = NULL -- Maximum size in MB for a table to be included
53
+ -- end of --
54
+ ) as
55
+ BEGIN
56
+ set nocount on ;
57
+
58
+ select quotename (object_schema_name (rg .object_id )) + ' .' + quotename (object_name (rg .object_id )) as [Table Name],
59
+ rg .partition_number ,
60
+ rg .row_group_id ,
61
+ rg .state ,
62
+ rg .state_description ,
63
+ rg .total_rows ,
64
+ rg .deleted_rows ,
65
+ cast (isnull (rg .size_in_bytes ,0 ) / 1024 . / 1024 as Decimal (8 ,3 )) as [Size in MB]
66
+ from sys .column_store_row_groups rg
67
+ where rg .total_rows <> case @showTrimmedGroupsOnly when 1 then 1048576 else - 1 end
68
+ and rg .state <> case @showNonCompressedOnly when 0 then - 1 else 3 end
69
+ and isnull (rg .deleted_rows ,0 ) <> case @showFragmentedGroupsOnly when 1 then 0 else - 1 end
70
+ and (@tableName is null or object_name (rg .object_id ) like ' %' + @tableName + ' %' )
71
+ and (@schemaName is null or object_schema_name (rg .object_id ) = @schemaName)
72
+ and rg .partition_number = case @partitionNumber when 0 then rg .partition_number else @partitionNumber end
73
+ and cast (isnull (rg .size_in_bytes ,0 ) / 1024 . / 1024 as Decimal (8 ,3 )) >= isnull (@minSizeInMB,0 .)
74
+ and cast (isnull (rg .size_in_bytes ,0 ) / 1024 . / 1024 as Decimal (8 ,3 )) <= isnull (@maxSizeInMB,999999999 .)
75
+ order by quotename (object_schema_name (rg .object_id )) + ' .' + quotename (object_name (rg .object_id )), rg .row_group_id ;
76
+ END
0 commit comments