备注 | 修改日期 | 修改人 |
格式调整 | 2023-12-28 09:07:57[当前版本] | 系统管理员 |
CREAT | 2020-05-22 17:20:35 | 系统管理员 |
操作系统是Windows2008R2 ,数据库是SQL2014 64位。
近阶段服务器出现过几次死机,管理员反馈机器内存使用率100%导致机器卡死。于是做了个监测服务器的软件实时记录CPU数据,几日观察得出数据如下:
SQL优化方法:
USE master
GO
--如果要指定数据库就把注释去掉
SELECT * FROM sys.[sysprocesses]
WHERE [spid]>50 --AND DB_NAME([dbid])='gposdb'
当前连接对象有67个其中‘WINAME’的主机名,‘jTDS’的进程名不属于已知常用软件,找到这台主机并解决连接问题。在360流量防火墙中查看有哪个软件连接了服务器IP,除之。
正常情况下搜索结果应该为空。
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])='gposdb'
ORDER BY [cpu_time] DESC
查看是哪些SQL语句占用较大可以使用下面代码
--在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
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
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
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;