1、查询sql server数据库中某表(tablename)的读写次数:
SELECT OBJECT_SCHEMA_NAME(ddius.object_id) + '.' + OBJECT_NAME(ddius.object_id) AS [Object Name], CASE WHEN (SUM(user_updates + user_seeks + user_scans + user_lookups)=0) THEN NULL ELSE CONVERT(DECIMAL(38,2),CAST(SUM(user_seeks + user_scans + user_lookups) AS DECIMAL) / CAST(SUM(user_updates + user_seeks + user_scans + user_lookups) AS DECIMAL)) END AS [Proportion of Reads], CASE WHEN (SUM(user_updates + user_seeks + user_scans + user_lookups)=0) THEN NULL ELSE CONVERT(DECIMAL(38,2),CAST(SUM(user_updates) AS DECIMAL) / CAST(SUM(user_updates + user_seeks + user_scans + user_lookups) AS DECIMAL)) END AS [Proportion of Writes],SUM(user_seeks + user_scans + user_lookups) AS [Total Read Operations], SUM(user_updates) AS [Total Write Operations] FROM sys.dm_db_index_usage_stats AS ddius JOIN sys.indexes AS i ON ddius.object_id=i.object_id AND ddius.index_id=i.index_id WHERE i.type_desc IN ('CLUSTERED','HEAP') --only works in Current db AND OBJECT_NAME(ddius.object_id)='tablename' GROUP BY ddius.object_id ORDER BY OBJECT_SCHEMA_NAME(ddius.object_id) + '.' + OBJECT_NAME(ddius.object_id);
–一般排查都是用下面的脚本,一般会用到三个视图sys.sysprocesses ,dm_exec_sessions ,dm_exec_requests
2、当前的数据库用户连接
SELECT * FROM sys.[sysprocesses] WHERE [spid]>50 and DB_NAME([dbid])='BPMProduct_ZLDC_5.1'; SELECT COUNT(*) FROM [sys].[dm_exec_sessions] WHERE [session_id]>50
3、前10个最耗CPU时间的会话
SELECT TOP 10 [session_id], [request_id], [start_time] AS '开始时间', [status] AS '状态', [command] AS '命令', dest.[text] AS 'sql语句', DB_NAME([database_id]) AS '数据库名', [blocking_session_id] AS '正在阻塞其他会话的会话ID', [wait_type] AS '等待资源类型', [wait_time] AS '等待时间', [wait_resource] AS '等待的资源', [reads] AS '物理读次数', [writes] AS '写次数', [logical_reads] AS '逻辑读次数', [row_count] AS '返回结果行数' FROM sys.[dm_exec_requests] AS der CROSS APPLY sys.[dm_exec_sql_text](der.[sql_handle]) AS dest WHERE [session_id]>50 AND DB_NAME(der.[database_id])='BPMProduct_ZLDC_5.1' ORDER BY [cpu_time] DESC
–在SSMS里选择以文本格式显示结果
SELECT TOP 10 dest.[text] AS 'sql语句' FROM sys.[dm_exec_requests] AS der CROSS APPLY sys.[dm_exec_sql_text](der.[sql_handle]) AS dest WHERE [session_id]>50 ORDER BY [cpu_time] DESC
4、查看CPU数和user scheduler数目
–查看CPU数和user scheduler数和最大工作线程数,检查worker是否用完也可以排查CPU占用情况
SELECT cpu_count,scheduler_count FROM sys.dm_os_sys_info
5、查看最大工作线程数
SELECT max_workers_count FROM sys.dm_os_sys_info
SELECT scheduler_address, scheduler_id, cpu_id, status, current_tasks_count, current_workers_count,active_workers_count FROM sys.dm_os_schedulers
6、查看等待资源
–如果SQLSERVER存在要等待的资源,那么执行下面语句就会显示出会话中有多少个worker在等待
SELECT TOP 10 [session_id], [request_id], [start_time] AS '开始时间', [status] AS '状态', [command] AS '命令', dest.[text] AS 'sql语句', DB_NAME([database_id]) AS '数据库名', [blocking_session_id] AS '正在阻塞其他会话的会话ID', der.[wait_type] AS '等待资源类型', [wait_time] AS '等待时间', [wait_resource] AS '等待的资源', [dows].[waiting_tasks_count] AS '当前正在进行等待的任务数', [reads] AS '物理读次数', [writes] AS '写次数', [logical_reads] AS '逻辑读次数', [row_count] AS '返回结果行数' FROM sys.[dm_exec_requests] AS der INNER JOIN [sys].[dm_os_wait_stats] AS dows ON der.[wait_type]=[dows].[wait_type] CROSS APPLY sys.[dm_exec_sql_text](der.[sql_handle]) AS dest WHERE [session_id]>50 ORDER BY [cpu_time] DESC
7、查询CPU占用高的语句
SELECT TOP 10 total_worker_time/execution_count AS avg_cpu_cost, plan_handle, execution_count, (SELECT SUBSTRING(text, statement_start_offset/2 + 1, (CASE WHEN statement_end_offset = -1 THEN LEN(CONVERT(nvarchar(max), text)) * 2 ELSE statement_end_offset END - statement_start_offset)/2) FROM sys.dm_exec_sql_text(sql_handle)) AS query_text FROM sys.dm_exec_query_stats ORDER BY [avg_cpu_cost] DESC
8、查询缺失索引
SELECT DatabaseName = DB_NAME(database_id) ,[Number Indexes Missing] = count(*) FROM sys.dm_db_missing_index_details GROUP BY DB_NAME(database_id) ORDER BY 2 DESC;
SELECT TOP 10 [Total Cost] = ROUND(avg_total_user_cost * avg_user_impact * (user_seeks + user_scans),0) , avg_user_impact , TableName = statement , [EqualityUsage] = equality_columns , [InequalityUsage] = inequality_columns , [Include Cloumns] = included_columns FROM sys.dm_db_missing_index_groups g INNER JOIN sys.dm_db_missing_index_group_stats s ON s.group_handle = g.index_group_handle INNER JOIN sys.dm_db_missing_index_details d ON d.index_handle = g.index_handle ORDER BY [Total Cost] DESC;
评论前必须登录!
注册