Skip to content

Commit fcb2bff

Browse files
1.0.3 Partial Update 4
1 parent fd29cbb commit fcb2bff

17 files changed

+209
-37
lines changed

Azure/StoredProcs/cstore_GetRowGroups.sql

+4-2
Original file line numberDiff line numberDiff line change
@@ -23,6 +23,7 @@ Known Issues & Limitations:
2323
2424
Changes in 1.0.3
2525
+ Added parameter for showing aggregated information on the whole table, instead of partitioned view as before
26+
* Changed the name of the @tableNamePattern to @tableName to follow the same standard across all CISL functions
2627
*/
2728

2829
declare @SQLServerVersion nvarchar(128) = cast(SERVERPROPERTY('ProductVersion') as NVARCHAR(128)),
@@ -47,7 +48,7 @@ create procedure dbo.cstore_GetRowGroups(
4748
@compressionType varchar(15) = NULL, -- Allows to filter by the compression type with following values 'ARCHIVE', 'COLUMNSTORE' or NULL for both
4849
@minTotalRows bigint = 000000, -- Minimum number of rows for a table to be included
4950
@minSizeInGB Decimal(16,3) = 0.00, -- Minimum size in GB for a table to be included
50-
@tableNamePattern nvarchar(256) = NULL, -- Allows to show data filtered down to the specified table name pattern
51+
@tableName nvarchar(256) = NULL, -- Allows to show data filtered down to the specified table name pattern
5152
@schemaName nvarchar(256) = NULL, -- Allows to show data filtered down to the specified schema
5253
@showPartitionDetails bit = 1 -- Allows to show details of each of the available partitions
5354
-- end of --
@@ -62,6 +63,7 @@ begin
6263
sum(case state when 0 then 1 else 0 end) as 'Bulk Load RG',
6364
sum(case state when 1 then 1 else 0 end) as 'Open DS',
6465
sum(case state when 2 then 1 else 0 end) as 'Closed DS',
66+
sum(case state when 4 then 1 else 0 end) as 'Tombstones',
6567
sum(case state when 3 then 1 else 0 end) as 'Compressed',
6668
count(*) as 'Total',
6769
cast( sum(isnull(deleted_rows,0))/1000000. as Decimal(16,6)) as 'Deleted Rows (M)',
@@ -82,7 +84,7 @@ begin
8284
and part.data_compression_desc in ('COLUMNSTORE','COLUMNSTORE_ARCHIVE')
8385
and case @indexType when 'CC' then 5 when 'NC' then 6 else ind.type end = ind.type
8486
and case @compressionType when 'Columnstore' then 3 when 'Archive' then 4 else part.data_compression end = part.data_compression
85-
and (@tableNamePattern is null or object_name (rg.object_id) like '%' + @tableNamePattern + '%')
87+
and (@tableName is null or object_name (rg.object_id) like '%' + @tableName + '%')
8688
and (@schemaName is null or object_schema_name(rg.object_id) = @schemaName)
8789
group by ind.object_id, ind.type, (case @showPartitionDetails when 1 then part.partition_number else 1 end)--, part.data_compression_desc
8890
having cast( sum(isnull(size_in_bytes,0) / 1024. / 1024 / 1024) as Decimal(8,2)) >= @minSizeInGB

Azure/StoredProcs/cstore_GetRowGroupsDetails.sql

+1-1
Original file line numberDiff line numberDiff line change
@@ -66,5 +66,5 @@ BEGIN
6666
and rg.partition_number = case @partitionNumber when 0 then rg.partition_number else @partitionNumber end
6767
and cast(isnull(rg.size_in_bytes,0) / 1024. / 1024 as Decimal(8,3)) >= isnull(@minSizeInMB,0.)
6868
and cast(isnull(rg.size_in_bytes,0) / 1024. / 1024 as Decimal(8,3)) <= isnull(@maxSizeInMB,999999999.)
69-
order by quotename(object_schema_name(rg.object_id)) + '.' + quotename(object_name(rg.object_id)), rg.row_group_id;
69+
order by quotename(object_schema_name(rg.object_id)) + '.' + quotename(object_name(rg.object_id)), rg.partition_number, rg.row_group_id
7070
END

Azure/row_groups.sql

+7-5
Original file line numberDiff line numberDiff line change
@@ -19,18 +19,19 @@
1919
*/
2020

2121
/*
22-
Known Issues & Limitations:
22+
Known Issues & Limitations:
2323
24-
Changes in 1.0.3
25-
+ Added parameter for showing aggregated information on the whole table, instead of partitioned view as before
24+
Changes in 1.0.3
25+
+ Added parameter for showing aggregated information on the whole table, instead of partitioned view as before
26+
* Changed the name of the @tableNamePattern to @tableName to follow the same standard across all CISL functions
2627
*/
2728

2829
-- Params --
2930
declare @indexType char(2) = NULL, -- Allows to filter Columnstore Indexes by their type, with possible values (CC for 'Clustered', NC for 'Nonclustered' or NULL for both)
3031
@compressionType varchar(15) = NULL, -- Allows to filter by the compression type with following values 'ARCHIVE', 'COLUMNSTORE' or NULL for both
3132
@minTotalRows bigint = 000000, -- Minimum number of rows for a table to be included
3233
@minSizeInGB Decimal(16,3) = 0.00, -- Minimum size in GB for a table to be included
33-
@tableNamePattern nvarchar(256) = NULL, -- Allows to show data filtered down to the specified table name pattern
34+
@tableName nvarchar(256) = NULL, -- Allows to show data filtered down to the specified table name pattern
3435
@schemaName nvarchar(256) = NULL, -- Allows to show data filtered down to the specified schema
3536
@showPartitionDetails bit = 1; -- Allows to show details of each of the available partitions
3637
-- end of --
@@ -55,6 +56,7 @@ select quotename(object_schema_name(ind.object_id)) + '.' + quotename(object_nam
5556
sum(case state when 0 then 1 else 0 end) as 'Bulk Load RG',
5657
sum(case state when 1 then 1 else 0 end) as 'Open DS',
5758
sum(case state when 2 then 1 else 0 end) as 'Closed DS',
59+
sum(case state when 4 then 1 else 0 end) as 'Tombstones',
5860
sum(case state when 3 then 1 else 0 end) as 'Compressed',
5961
count(*) as 'Total',
6062
cast( sum(isnull(deleted_rows,0))/1000000. as Decimal(16,6)) as 'Deleted Rows (M)',
@@ -75,7 +77,7 @@ select quotename(object_schema_name(ind.object_id)) + '.' + quotename(object_nam
7577
and part.data_compression_desc in ('COLUMNSTORE','COLUMNSTORE_ARCHIVE')
7678
and case @indexType when 'CC' then 5 when 'NC' then 6 else ind.type end = ind.type
7779
and case @compressionType when 'Columnstore' then 3 when 'Archive' then 4 else part.data_compression end = part.data_compression
78-
and (@tableNamePattern is null or object_name (rg.object_id) like '%' + @tableNamePattern + '%')
80+
and (@tableName is null or object_name (rg.object_id) like '%' + @tableName + '%')
7981
and (@schemaName is null or object_schema_name(rg.object_id) = @schemaName)
8082
group by ind.object_id, ind.type, (case @showPartitionDetails when 1 then part.partition_number else 1 end)--, part.data_compression_desc
8183
having cast( sum(isnull(size_in_bytes,0) / 1024. / 1024 / 1024) as Decimal(8,2)) >= @minSizeInGB

Azure/row_groups_details.sql

+1-1
Original file line numberDiff line numberDiff line change
@@ -59,4 +59,4 @@ select quotename(object_schema_name(rg.object_id)) + '.' + quotename(object_name
5959
and rg.partition_number = case @partitionNumber when 0 then rg.partition_number else @partitionNumber end
6060
and cast(isnull(rg.size_in_bytes,0) / 1024. / 1024 as Decimal(8,3)) >= isnull(@minSizeInMB,0.)
6161
and cast(isnull(rg.size_in_bytes,0) / 1024. / 1024 as Decimal(8,3)) <= isnull(@maxSizeInMB,999999999.)
62-
order by quotename(object_schema_name(rg.object_id)) + '.' + quotename(object_name(rg.object_id)), rg.row_group_id
62+
order by quotename(object_schema_name(rg.object_id)) + '.' + quotename(object_name(rg.object_id)), rg.partition_number, rg.row_group_id

SQL-2012/StoredProcs/cstore_GetRowGroups.sql

+11-6
Original file line numberDiff line numberDiff line change
@@ -19,7 +19,11 @@
1919
*/
2020

2121
/*
22-
Known Issues & Limitations:
22+
Known Issues & Limitations:
23+
24+
Changes in 1.0.3
25+
+ Added parameter for showing aggregated information on the whole table, instead of partitioned view as before
26+
* Changed the name of the @tableNamePattern to @tableName to follow the same standard across all CISL functions
2327
*/
2428

2529
declare @SQLServerVersion nvarchar(128) = cast(SERVERPROPERTY('ProductVersion') as NVARCHAR(128)),
@@ -50,16 +54,17 @@ create procedure dbo.cstore_GetRowGroups(
5054
@compressionType varchar(15) = NULL, -- Allows to filter by the compression type with following values 'ARCHIVE', 'COLUMNSTORE' or NULL for both
5155
@minTotalRows bigint = 000000, -- Minimum number of rows for a table to be included
5256
@minSizeInGB Decimal(16,3) = 0.00, -- Minimum size in GB for a table to be included
53-
@tableNamePattern nvarchar(256) = NULL, -- Allows to show data filtered down to the specified table name pattern
54-
@schemaName nvarchar(256) = NULL -- Allows to show data filtered down to the specified schema
57+
@tableName nvarchar(256) = NULL, -- Allows to show data filtered down to the specified table name pattern
58+
@schemaName nvarchar(256) = NULL, -- Allows to show data filtered down to the specified schema
59+
@showPartitionDetails bit = 1; -- Allows to show details of each of the available partitions
5560
-- end of --
5661
) as
5762
begin
5863
set nocount on;
5964

6065
select quotename(object_schema_name(ind.object_id)) + '.' + quotename(object_name(ind.object_id)) as 'TableName',
6166
case ind.type when 5 then 'Clustered' when 6 then 'Nonclustered' end as 'Type',
62-
part.partition_number as 'Partition',
67+
(case @showPartitionDetails when 1 then part.partition_number else 1 end) as 'Partition',
6368
part.data_compression_desc as 'Compression Type',
6469
0 as 'Bulk Load RG',
6570
0 as 'Open DS',
@@ -83,13 +88,13 @@ begin
8388
where ind.type in (5,6) -- Clustered & Nonclustered Columnstore
8489
and part.data_compression_desc in ('COLUMNSTORE')
8590
and case @compressionType when 'Columnstore' then 3 when 'Archive' then 4 else part.data_compression end = part.data_compression
86-
and (@tableNamePattern is null or object_name (part.object_id) like '%' + @tableNamePattern + '%')
91+
and (@tableName is null or object_name (part.object_id) like '%' + @tableName + '%')
8792
and (@schemaName is null or object_schema_name(part.object_id) = @schemaName)
8893
group by ind.object_id, ind.type, part.partition_number, part.data_compression_desc
8994
having cast( sum(isnull(on_disk_size,0) / 1024. / 1024 / 1024) as Decimal(8,2)) >= @minSizeInGB
9095
and sum(isnull(row_count,0)) >= @minTotalRows
9196
order by quotename(object_schema_name(ind.object_id)) + '.' + quotename(object_name(ind.object_id)),
92-
part.partition_number;
97+
(case @showPartitionDetails when 1 then part.partition_number else 1 end);
9398

9499
end
95100

Original file line numberDiff line numberDiff line change
@@ -0,0 +1,80 @@
1+
/*
2+
Columnstore Indexes Scripts Library for SQL Server 2012:
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 2012
26+
if substring(@SQLServerVersion,1,CHARINDEX('.',@SQLServerVersion)-1) <> N'11'
27+
begin
28+
set @errorMessage = (N'You are not running a SQL Server 2012. 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 2012 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(part.object_id)) + '.' + quotename(object_name(part.object_id)) as 'TableName',
59+
part.partition_number,
60+
rg.segment_id as row_group_id,
61+
3 as state,
62+
'COMPRESSED' as state_description,
63+
sum(rg.row_count)/count(distinct rg.column_id) as total_rows,
64+
0 as deleted_rows,
65+
cast(sum(isnull(rg.on_disk_size,0)) / 1024. / 1024 as Decimal(8,3)) as [Size in MB]
66+
from sys.column_store_segments rg
67+
left join sys.partitions part with(READUNCOMMITTED)
68+
on rg.hobt_id = part.hobt_id and isnull(rg.partition_id,1) = part.partition_id
69+
where 1 = case @showNonCompressedOnly when 0 then 1 else -1 end
70+
and 1 = case @showFragmentedGroupsOnly when 1 then 0 else 1 end
71+
and (@tableName is null or object_name (part.object_id) like '%' + @tableName + '%')
72+
and (@schemaName is null or object_schema_name(part.object_id) = @schemaName)
73+
and part.partition_number = case @partitionNumber when 0 then part.partition_number else @partitionNumber end
74+
group by part.object_id, part.partition_number, rg.segment_id
75+
having sum(rg.row_count)/count(distinct rg.column_id) <> case @showTrimmedGroupsOnly when 1 then 1048576 else -1 end
76+
and cast(sum(isnull(rg.on_disk_size,0)) / 1024. / 1024 as Decimal(8,3)) >= isnull(@minSizeInMB,0.)
77+
and cast(sum(isnull(rg.on_disk_size,0)) / 1024. / 1024 as Decimal(8,3)) <= isnull(@maxSizeInMB,999999999.)
78+
order by quotename(object_schema_name(part.object_id)) + '.' + quotename(object_name(part.object_id)),
79+
part.partition_number, rg.segment_id
80+
END

SQL-2012/row_groups.sql

+11-6
Original file line numberDiff line numberDiff line change
@@ -19,16 +19,21 @@
1919
*/
2020

2121
/*
22-
Known Issues & Limitations:
22+
Known Issues & Limitations:
23+
24+
Changes in 1.0.3
25+
+ Added parameter for showing aggregated information on the whole table, instead of partitioned view as before
26+
* Changed the name of the @tableNamePattern to @tableName to follow the same standard across all CISL functions
2327
*/
2428

2529
-- Params --
2630
declare @indexType char(2) = NULL, -- Ignored for this version
2731
@compressionType varchar(15) = NULL, -- Allows to filter by the compression type with following values 'ARCHIVE', 'COLUMNSTORE' or NULL for both
2832
@minTotalRows bigint = 000000, -- Minimum number of rows for a table to be included
2933
@minSizeInGB Decimal(16,3) = 0.00, -- Minimum size in GB for a table to be included
30-
@tableNamePattern nvarchar(256) = NULL, -- Allows to show data filtered down to the specified table name pattern
31-
@schemaName nvarchar(256) = NULL; -- Allows to show data filtered down to the specified schema
34+
@tableName nvarchar(256) = NULL, -- Allows to show data filtered down to the specified table name pattern
35+
@schemaName nvarchar(256) = NULL, -- Allows to show data filtered down to the specified schema
36+
@showPartitionDetails bit = 1; -- Allows to show details of each of the available partitions
3237
-- end of --
3338

3439
declare @SQLServerVersion nvarchar(128) = cast(SERVERPROPERTY('ProductVersion') as NVARCHAR(128)),
@@ -52,7 +57,7 @@ set nocount on;
5257

5358
select quotename(object_schema_name(ind.object_id)) + '.' + quotename(object_name(ind.object_id)) as 'TableName',
5459
case ind.type when 5 then 'Clustered' when 6 then 'Nonclustered' end as 'Type',
55-
part.partition_number as 'Partition',
60+
(case @showPartitionDetails when 1 then part.partition_number else 1 end) as 'Partition',
5661
part.data_compression_desc as 'Compression Type',
5762
0 as 'Bulk Load RG',
5863
0 as 'Open DS',
@@ -76,10 +81,10 @@ select quotename(object_schema_name(ind.object_id)) + '.' + quotename(object_nam
7681
where ind.type in (5,6) -- Clustered & Nonclustered Columnstore
7782
and part.data_compression_desc in ('COLUMNSTORE')
7883
and case @compressionType when 'Columnstore' then 3 when 'Archive' then 4 else part.data_compression end = part.data_compression
79-
and (@tableNamePattern is null or object_name (part.object_id) like '%' + @tableNamePattern + '%')
84+
and (@tableName is null or object_name (part.object_id) like '%' + @tableName + '%')
8085
and (@schemaName is null or object_schema_name(part.object_id) = @schemaName)
8186
group by ind.object_id, ind.type, part.partition_number, part.data_compression_desc
8287
having cast( sum(isnull(on_disk_size,0) / 1024. / 1024 / 1024) as Decimal(8,2)) >= @minSizeInGB
8388
and sum(isnull(row_count,0)) >= @minTotalRows
8489
order by quotename(object_schema_name(ind.object_id)) + '.' + quotename(object_name(ind.object_id)),
85-
part.partition_number;
90+
(case @showPartitionDetails when 1 then part.partition_number else 1 end);

0 commit comments

Comments
 (0)