-
Notifications
You must be signed in to change notification settings - Fork 3
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge pull request #3 from MadeiraData/revamped_ssrs_reports
Revamped ssrs reports
- Loading branch information
Showing
27 changed files
with
13,172 additions
and
2,286 deletions.
There are no files selected for viewing
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
94 changes: 94 additions & 0 deletions
94
sql-queries/visualize_page_allocation_compact_v2_SQL2012.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,94 @@ | ||
DECLARE @DatabaseName sysname = DB_NAME(), @ObjectName sysname = '[CyberProfiles].[Profile]', @ObjectType sysname = 'Table' | ||
|
||
SET NOCOUNT ON; | ||
DECLARE @IndexId int = NULL, @TableId int = NULL; | ||
|
||
IF @ObjectType = 'Index' | ||
BEGIN | ||
SELECT @TableId = object_id | ||
FROM sys.indexes | ||
WHERE name = @ObjectName | ||
|
||
IF @@ROWCOUNT <> 1 RAISERROR(N'Unable to determine table to which index "%s" belongs', 16, 1, @ObjectName); | ||
|
||
SET @IndexId = INDEXPROPERTY(@TableId, @ObjectName, 'IndexID'); | ||
END | ||
ELSE IF @ObjectType = 'Table' | ||
BEGIN | ||
SET @TableId = OBJECT_ID(@ObjectName); | ||
END | ||
ELSE | ||
BEGIN | ||
RAISERROR(N'Object Type "%s" is not supported', 16, 1, @ObjectType); | ||
END | ||
|
||
SELECT | ||
databse_name = DB_NAME() | ||
, file_name | ||
, page_identifier = CONCAT(file_id,':',pt.from_page_id) | ||
, check_file_total_size = file_total_size | ||
, check_file_total_used_space = file_total_used_space | ||
, check_file_total_unused_pages = file_total_unused_pages | ||
, agg_file_total_reserved_pages = file_total_reserved_pages | ||
, agg_file_total_consecutive_unused_pages = SUM(pt.consecutive_unused_pages) OVER (PARTITION BY file_id) | ||
, pt.* | ||
, pages_in_range = pt.to_page_id - pt.from_page_id + 1 | ||
FROM | ||
( | ||
SELECT | ||
databse_name = DB_NAME() | ||
, file_id | ||
, file_name | ||
, file_total_size | ||
, file_total_used_space | ||
, file_total_unused_pages = file_total_size - file_total_reserved_pages + 1 | ||
, file_total_reserved_pages | ||
, prev_used_page | ||
, from_used_page_id = allocated_page_page_id | ||
, to_page_id = ISNULL(NULLIF(next_used_page,file_total_size-1) - 1, next_used_page) | ||
, consecutive_unused_pages = ISNULL(NULLIF(next_used_page,file_total_size-1) - 1, next_used_page) - allocated_page_page_id | ||
, next_used_page_id = LEAD(allocated_page_page_id,1,file_total_size-1) OVER(PARTITION BY file_id ORDER BY allocated_page_page_id ASC) | ||
FROM | ||
( | ||
SELECT | ||
database_id = DB_ID() | ||
, f.file_id | ||
, f.file_name | ||
, f.file_total_used_space | ||
, f.file_total_size | ||
, file_total_reserved_pages = COUNT(*) OVER() + 9 | ||
, p.allocated_page_page_id | ||
, prev_used_page = LAG(p.allocated_page_page_id,1,0) OVER (PARTITION BY f.file_id ORDER BY p.allocated_page_page_id ASC) | ||
, next_used_page = LEAD(p.allocated_page_page_id,1,f.file_total_size - 1) OVER (PARTITION BY f.file_id ORDER BY p.allocated_page_page_id ASC) | ||
FROM sys.dm_db_database_page_allocations(DB_ID(@DatabaseName),default,default,default,'DETAILED') AS p | ||
INNER JOIN ( | ||
SELECT file_id, file_name = [name], size AS file_total_size | ||
, file_total_used_space = FILEPROPERTY([name], 'SpaceUsed') | ||
FROM sys.database_files AS f | ||
WHERE type = 0 | ||
) AS f | ||
ON f.file_id = p.allocated_page_file_id | ||
) AS sub1 | ||
WHERE sub1.next_used_page <> sub1.allocated_page_page_id + 1 | ||
) AS sub2 | ||
CROSS APPLY | ||
( | ||
SELECT usage = 'EMPTY' | ||
, from_page_id = from_used_page_id + 1 | ||
, to_page_id = sub2.to_page_id | ||
, consecutive_unused_pages = sub2.consecutive_unused_pages | ||
UNION ALL | ||
SELECT | ||
usage = 'USED' | ||
, 0 | ||
, sub2.from_used_page_id | ||
, 0 | ||
WHERE prev_used_page = 0 | ||
UNION ALL | ||
SELECT | ||
usage = 'USED' | ||
, sub2.to_page_id + 1 | ||
, sub2.next_used_page_id | ||
, 0 | ||
WHERE next_used_page_id < file_total_size-1 | ||
) AS pt |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
60 changes: 60 additions & 0 deletions
60
sql-queries/visualize_page_allocation_detailed_zoomable_SQL2012.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,60 @@ | ||
DECLARE @DatabaseName sysname = DB_NAME(), @ObjectName sysname = '[CyberProfiles].[Profile]', @ObjectType sysname = 'Table', @MaxItems int = 128 | ||
DECLARE @FileId int = NULL, @FromPage bigint = 0, @ToPage bigint = NULL | ||
|
||
SET NOCOUNT ON; | ||
DECLARE @IndexId int = NULL, @TableId int = NULL; | ||
|
||
IF @ObjectType = 'Index' | ||
BEGIN | ||
SELECT @TableId = object_id | ||
FROM sys.indexes | ||
WHERE name = @ObjectName | ||
|
||
IF @@ROWCOUNT <> 1 RAISERROR(N'Unable to determine table to which index "%s" belongs', 16, 1, @ObjectName); | ||
|
||
SET @IndexId = INDEXPROPERTY(@TableId, @ObjectName, 'IndexID'); | ||
END | ||
ELSE IF @ObjectType = 'Table' | ||
BEGIN | ||
SET @TableId = OBJECT_ID(@ObjectName); | ||
END | ||
ELSE IF @ObjectType <> 'Database' | ||
BEGIN | ||
RAISERROR(N'Object Type "%s" is not supported', 16, 1, @ObjectType); | ||
END | ||
|
||
SELECT | ||
f.file_name | ||
, f.file_id | ||
, p.PageGroup | ||
, from_page_id = MIN(p.page_id) | ||
, to_page_id = MAX(p.page_id) | ||
, page_count = COUNT(p.page_id) | ||
, free_kb = SUM(p.free_bytes) / 1024 | ||
, used_kb = SUM(p.used_bytes) / 1024 | ||
FROM | ||
( | ||
SELECT p.allocated_page_file_id | ||
, page_id = p.allocated_page_page_id | ||
, p.page_type | ||
, page_type_desc = ISNULL(p.page_type_desc, 'EMPTY') | ||
, free_bytes = CASE WHEN ISNULL(p.page_type_desc, 'EMPTY') = 'EMPTY' THEN 8192 ELSE ISNULL((100 - p.page_free_space_percent) / 100.0 * 8192, 0) END | ||
, used_bytes = CASE WHEN ISNULL(p.page_type_desc, 'EMPTY') = 'EMPTY' THEN 0 ELSE ISNULL(p.page_free_space_percent / 100.0 * 8192, 8192) END | ||
, PageGroup = NTILE(@MaxItems) OVER(ORDER BY p.allocated_page_page_id) | ||
FROM sys.dm_db_database_page_allocations(DB_ID(@DatabaseName),@TableId,@IndexId,default,'DETAILED') AS p | ||
WHERE (@FileId IS NULL OR p.allocated_page_file_id = @FileId) | ||
AND (@FromPage IS NULL OR p.allocated_page_page_id >= @FromPage) | ||
AND (@ToPage IS NULL OR p.allocated_page_page_id <= @ToPage) | ||
) AS p | ||
INNER JOIN | ||
( | ||
SELECT file_id, file_name = [name], size AS file_total_size | ||
, file_total_used_space = FILEPROPERTY([name], 'SpaceUsed') | ||
FROM sys.database_files AS f | ||
WHERE type = 0 | ||
) AS f | ||
ON f.file_id = p.allocated_page_file_id | ||
GROUP BY | ||
f.file_name | ||
, f.file_id | ||
, p.PageGroup |
61 changes: 61 additions & 0 deletions
61
sql-queries/visualize_page_allocation_detailed_zoomable_SQL2019.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,61 @@ | ||
DECLARE @DatabaseName sysname = DB_NAME(), @ObjectName sysname = '[CyberProfiles].[Profile]', @ObjectType sysname = 'Table', @MaxItems int = 128 | ||
DECLARE @FileId int = NULL, @FromPage bigint = 0, @ToPage bigint = NULL | ||
|
||
SET NOCOUNT ON; | ||
DECLARE @IndexId int = NULL, @TableId int = NULL; | ||
|
||
IF @ObjectType = 'Index' | ||
BEGIN | ||
SELECT @TableId = object_id | ||
FROM sys.indexes | ||
WHERE name = @ObjectName | ||
|
||
IF @@ROWCOUNT <> 1 RAISERROR(N'Unable to determine table to which index "%s" belongs', 16, 1, @ObjectName); | ||
|
||
SET @IndexId = INDEXPROPERTY(@TableId, @ObjectName, 'IndexID'); | ||
END | ||
ELSE IF @ObjectType = 'Table' | ||
BEGIN | ||
SET @TableId = OBJECT_ID(@ObjectName); | ||
END | ||
ELSE IF @ObjectType <> 'Database' | ||
BEGIN | ||
RAISERROR(N'Object Type "%s" is not supported', 16, 1, @ObjectType); | ||
END | ||
|
||
SELECT | ||
f.file_name | ||
, f.file_id | ||
, p.PageGroup | ||
, from_page_id = MIN(p.page_id) | ||
, to_page_id = MAX(p.page_id) | ||
, page_count = COUNT(p.page_id) | ||
, free_kb = SUM(ISNULL(pinfo.free_bytes, 8 * 1024)) / 1024 | ||
, used_kb = SUM(ISNULL(pinfo.free_bytes_offset, 0)) / 1024 | ||
FROM | ||
( | ||
SELECT p.allocated_page_file_id | ||
, page_id = p.allocated_page_page_id | ||
, p.page_type | ||
, page_type_desc = ISNULL(p.page_type_desc, 'EMPTY') | ||
, free_bytes = CASE WHEN ISNULL(p.page_type_desc, 'EMPTY') = 'EMPTY' THEN 8192 ELSE ISNULL((100 - p.page_free_space_percent) / 100.0 * 8192, 0) END | ||
, used_bytes = CASE WHEN ISNULL(p.page_type_desc, 'EMPTY') = 'EMPTY' THEN 0 ELSE ISNULL(p.page_free_space_percent / 100.0 * 8192, 8192) END | ||
, PageGroup = NTILE(@MaxItems) OVER(ORDER BY p.allocated_page_page_id) | ||
FROM sys.dm_db_database_page_allocations(DB_ID(@DatabaseName),@TableId,@IndexId,default,'DETAILED') AS p | ||
WHERE (@FileId IS NULL OR p.allocated_page_file_id = @FileId) | ||
AND (@FromPage IS NULL OR p.allocated_page_page_id >= @FromPage) | ||
AND (@ToPage IS NULL OR p.allocated_page_page_id <= @ToPage) | ||
) AS p | ||
INNER JOIN | ||
( | ||
SELECT file_id, file_name = [name], size AS file_total_size | ||
, file_total_used_space = FILEPROPERTY([name], 'SpaceUsed') | ||
FROM sys.database_files AS f | ||
WHERE type = 0 | ||
) AS f | ||
ON f.file_id = p.allocated_page_file_id | ||
OUTER APPLY sys.dm_db_page_info(DB_ID(@DatabaseName), f.file_id, p.page_id, 'DETAILED') AS pinfo | ||
GROUP BY | ||
f.file_name | ||
, f.file_id | ||
, p.PageGroup |
Oops, something went wrong.