mirror of
https://github.com/ckaczor/azuredatastudio.git
synced 2026-02-16 10:58:30 -05:00
SQL Operations Studio Public Preview 1 (0.23) release source code
This commit is contained in:
34
extensions/insights-default/sql/backup_detail.sql
Normal file
34
extensions/insights-default/sql/backup_detail.sql
Normal file
@@ -0,0 +1,34 @@
|
||||
declare @condition tinyint;
|
||||
SET @condition = 24;
|
||||
|
||||
select
|
||||
d.database_id as [Database ID],
|
||||
d.name as [Database],
|
||||
d.recovery_model_desc as [Recovery model],
|
||||
d.state_desc as [Database state],
|
||||
case
|
||||
when b.type = N'D' then N'Database'
|
||||
when b.type = N'I' then N'Differential Database'
|
||||
when b.type = N'L' then N'Log'
|
||||
when b.type = N'F' then N'File or Filegroup'
|
||||
when b.type = N'G' then N'Differental File'
|
||||
when b.type = N'P' then N'Partial'
|
||||
when b.type = N'Q' then N'Differential Partial'
|
||||
else NULL
|
||||
end
|
||||
as [Backup type],
|
||||
b.backup_start_date as [Backup start date],
|
||||
b.backup_finish_date as [Backup finish date],
|
||||
case
|
||||
when m.last_backup_time is null then N'No backup found'
|
||||
when datediff(hh, m.last_backup_time, getdate()) > @condition then N'Older than 24hrs'
|
||||
else N'Within 24hrs'
|
||||
end as [Backup_Health]
|
||||
from sys.databases as d
|
||||
left join msdb..backupset as b on d.name = b.database_name
|
||||
left join (select bs.database_name, max(bs.backup_start_date) as last_backup_time
|
||||
from msdb..backupset as bs
|
||||
group by bs.database_name ) as m on d.name = m.database_name and b.backup_start_date = m.last_backup_time
|
||||
where (b.backup_start_date is null or b.backup_start_date = m.last_backup_time)
|
||||
and d.database_id > 4
|
||||
order by d.database_id asc
|
||||
16
extensions/insights-default/sql/backup_insight.sql
Normal file
16
extensions/insights-default/sql/backup_insight.sql
Normal file
@@ -0,0 +1,16 @@
|
||||
declare @condition tinyint;
|
||||
SET @condition = 24;
|
||||
with
|
||||
backupInsight_cte (database_id, last_backup, health_check)
|
||||
as
|
||||
(
|
||||
select d.database_id, max(b.backup_start_date) AS last_backup, case when (datediff( hh , max(b.backup_start_date) , getdate()) < @condition) then 1 else 0 end as health_check
|
||||
from sys.databases as d left join msdb..backupset as b on d.name = b.database_name
|
||||
where d.database_id > 4
|
||||
group by d.database_id
|
||||
)
|
||||
select
|
||||
coalesce(sum(health_check),0) [Within 24hrs],
|
||||
coalesce(sum(case when health_check = 0 AND last_backup IS NOT NULL then 1 else 0 end),0) [Older than 24hrs],
|
||||
coalesce(sum(case when health_check = 0 AND last_backup IS NULL then 1 else 0 end),0) [No backup found]
|
||||
from backupInsight_cte
|
||||
13
extensions/insights-default/sql/db_size.sql
Normal file
13
extensions/insights-default/sql/db_size.sql
Normal file
@@ -0,0 +1,13 @@
|
||||
with fs
|
||||
as
|
||||
(
|
||||
select database_id, type, size * 8.0 / 1024 size
|
||||
from sys.master_files
|
||||
)
|
||||
select top 10
|
||||
name,
|
||||
(select sum(size) from fs where type = 0 and fs.database_id = db.database_id) DataFileSizeMB,
|
||||
(select sum(size) from fs where type = 1 and fs.database_id = db.database_id) LogFileSizeMB
|
||||
from sys.databases db
|
||||
where database_id > 4
|
||||
order by DataFileSizeMB
|
||||
39
extensions/insights-default/sql/qds.sql
Normal file
39
extensions/insights-default/sql/qds.sql
Normal file
@@ -0,0 +1,39 @@
|
||||
declare @qds_status int = (SELECT actual_state
|
||||
FROM sys.database_query_store_options)
|
||||
if @qds_status > 0
|
||||
Begin
|
||||
WITH SlowestQry AS(
|
||||
SELECT TOP 5
|
||||
q.query_id,
|
||||
MAX(rs.max_duration ) max_duration
|
||||
FROM sys.query_store_query_text AS qt
|
||||
JOIN sys.query_store_query AS q
|
||||
ON qt.query_text_id = q.query_text_id
|
||||
JOIN sys.query_store_plan AS p
|
||||
ON q.query_id = p.query_id
|
||||
JOIN sys.query_store_runtime_stats AS rs
|
||||
ON p.plan_id = rs.plan_id
|
||||
WHERE rs.last_execution_time > DATEADD(week, -1, GETUTCDATE())
|
||||
AND is_internal_query = 0
|
||||
GROUP BY q.query_id
|
||||
ORDER BY MAX(rs.max_duration ) DESC)
|
||||
SELECT
|
||||
q.query_id,
|
||||
format(rs.last_execution_time,'yyyy-MM-dd hh:mm:ss') as [last_execution_time],
|
||||
rs.max_duration,
|
||||
p.plan_id
|
||||
FROM sys.query_store_query_text AS qt
|
||||
JOIN sys.query_store_query AS q
|
||||
ON qt.query_text_id = q.query_text_id
|
||||
JOIN sys.query_store_plan AS p
|
||||
ON q.query_id = p.query_id
|
||||
JOIN sys.query_store_runtime_stats AS rs
|
||||
ON p.plan_id = rs.plan_id
|
||||
JOIN SlowestQry tq
|
||||
ON tq.query_id = q.query_id
|
||||
WHERE rs.last_execution_time > DATEADD(week, -1, GETUTCDATE())
|
||||
AND is_internal_query = 0
|
||||
order by format(rs.last_execution_time,'yyyy-MM-dd hh:mm:ss')
|
||||
END
|
||||
else
|
||||
select 0 as [query_id], getdate() as [QDS is not enabled], 0 as [max_duration]
|
||||
41
extensions/insights-default/sql/qds_detail.sql
Normal file
41
extensions/insights-default/sql/qds_detail.sql
Normal file
@@ -0,0 +1,41 @@
|
||||
declare @qds_status int = (SELECT actual_state
|
||||
FROM sys.database_query_store_options)
|
||||
if @qds_status > 0
|
||||
Begin
|
||||
WITH SlowestQry AS(
|
||||
SELECT TOP 5
|
||||
q.query_id,
|
||||
MAX(rs.max_duration ) max_duration
|
||||
FROM sys.query_store_query_text AS qt
|
||||
JOIN sys.query_store_query AS q
|
||||
ON qt.query_text_id = q.query_text_id
|
||||
JOIN sys.query_store_plan AS p
|
||||
ON q.query_id = p.query_id
|
||||
JOIN sys.query_store_runtime_stats AS rs
|
||||
ON p.plan_id = rs.plan_id
|
||||
WHERE rs.last_execution_time > DATEADD(week, -1, GETUTCDATE())
|
||||
AND is_internal_query = 0
|
||||
GROUP BY q.query_id
|
||||
ORDER BY MAX(rs.max_duration ) DESC)
|
||||
SELECT
|
||||
q.query_id,
|
||||
format(rs.last_execution_time,'yyyy-MM-dd hh:mm:ss') as [last_execution_time],
|
||||
rs.max_duration,
|
||||
p.plan_id ,
|
||||
qt.query_sql_text,
|
||||
p.query_plan
|
||||
FROM SlowestQry tq
|
||||
join sys.query_store_query as q
|
||||
on tq.query_id = q.query_id
|
||||
JOIN sys.query_store_query_text AS qt
|
||||
ON qt.query_text_id = q.query_text_id
|
||||
JOIN sys.query_store_plan AS p
|
||||
ON q.query_id = p.query_id
|
||||
JOIN sys.query_store_runtime_stats AS rs
|
||||
ON p.plan_id = rs.plan_id
|
||||
WHERE rs.last_execution_time > DATEADD(week, -1, GETUTCDATE())
|
||||
AND is_internal_query = 0
|
||||
order by q.query_id, rs.max_duration desc
|
||||
END
|
||||
else
|
||||
select 0 as [query_id], getdate() as [QDS is not enabled], 0 as [max_duration]
|
||||
25
extensions/insights-default/sql/tablespace.sql
Normal file
25
extensions/insights-default/sql/tablespace.sql
Normal file
@@ -0,0 +1,25 @@
|
||||
SELECT Top 5 TABL.name AS table_name,
|
||||
SUM(PART.rows) AS rows_count,
|
||||
SUM(ALOC.total_pages) AS total_pages,
|
||||
SUM(ALOC.used_pages) AS used_pages,
|
||||
SUM(ALOC.data_pages) AS data_pages,
|
||||
(SUM(ALOC.total_pages)*8/1024) AS total_space_MB,
|
||||
(SUM(ALOC.used_pages)*8/1024) AS used_space_MB,
|
||||
(SUM(ALOC.data_pages)*8/1024) AS data_space_MB
|
||||
FROM sys.Tables AS TABL
|
||||
INNER JOIN sys.Indexes AS INDX
|
||||
ON TABL.object_id = INDX.object_id
|
||||
INNER JOIN sys.Partitions AS PART
|
||||
ON INDX.object_id = PART.object_id
|
||||
AND INDX.index_id = PART.index_id
|
||||
INNER JOIN sys.Allocation_Units AS ALOC
|
||||
ON PART.partition_id = ALOC.container_id
|
||||
WHERE
|
||||
INDX.object_id > 255
|
||||
AND INDX.index_id <= 1
|
||||
GROUP BY TABL.name,
|
||||
INDX.object_id,
|
||||
INDX.index_id,
|
||||
INDX.name
|
||||
ORDER BY
|
||||
(SUM(ALOC.total_pages)*8/1024) DESC
|
||||
Reference in New Issue
Block a user