1、查询存储过程创建时间和修改时间
select [name],create_date,modify_date FROM sys.all_objects where type_desc = N'SQL_STORED_PROCEDURE' and name = '存储过程名'
2、修改恢复模式
USE [master]
GO
ALTER DATABASE 数据库名 SET RECOVERY 恢复模式名 WITH NO_WAIT
GO
3、查询SQLzhixin执行超时时间
select CONVERT(varchar,value) as value from sys.configurations where name like '%remote query timeout%'
4、查看当前运行的SQL
SELECT [Spid] = session_id ,
[Database] = DB_NAME(sp.dbid) ,
[User] = nt_username ,
[Status] = er.status ,
[Wait] = wait_type ,
[Individual Query] = SUBSTRING(qt.text,
er.statement_start_offset / 2,
( CASE WHEN er.statement_end_offset = -1
THEN LEN(CONVERT(NVARCHAR(MAX), qt.text))
* 2
ELSE er.statement_end_offset
END - er.statement_start_offset )
/ 2) ,
[Parent Query] = qt.text ,
Program = program_name ,
hostname ,
nt_domain ,
start_time
FROM sys.dm_exec_requests er
INNER JOIN sys.sysprocesses sp ON er.session_id = sp.spid
CROSS APPLY sys.dm_exec_sql_text(er.sql_handle) AS qt
WHERE session_id > 50
AND session_id NOT IN ( @@SPID )
5、JOB历史记录查询
--适用官方SQL Server
SELECT msdb.dbo.agent_datetime(h.run_date, h.run_time) AS 'RunDateTime' ,
h.run_date AS Run_Date ,
CAST(run_duration / 10000 AS VARCHAR(2)) + N'小时' + CAST(( run_duration - run_duration / 10000 * 10000 ) / 100 AS VARCHAR(2)) + N'分钟' + SUBSTRING(CAST(run_duration AS VARCHAR(10)),
LEN(CAST(run_duration AS VARCHAR(10))) - 1, 2) + N'秒' AS run_duration2,
j.name AS Job_Name ,
h.step_name AS Step_Name ,
h.run_status ,
h.message AS Message
FROM msdb.dbo.sysjobhistory h
LEFT JOIN msdb.dbo.sysjobs j
ON h.job_id = j.job_id
WHERE CONVERT(DATE,msdb.dbo.agent_datetime(h.run_date, h.run_time),121) = CONVERT(DATE,GETDATE())
AND h.step_id!=0
ORDER BY msdb.dbo.agent_datetime(h.run_date, h.run_time) DESC
--RDS不支持 msdb.dbo.agent_datetime,下面这个脚本代替,实现同样的效果,适用RDS For SQL Server
SELECT
convert(datetime,
left((cast(h.run_date as varchar)+cast(h.run_time as varchar)),4)+'-'
+substring((cast(h.run_date as varchar)+cast(h.run_time as varchar)),5,2)
+'-'+substring((cast(h.run_date as varchar)+cast(h.run_time as varchar)),7,2)
+' '+substring((cast(h.run_date as varchar)+cast(h.run_time as varchar)),9,2)
+':'+right((cast(h.run_date as varchar)+cast(h.run_time as varchar)),2)) AS RunDateTime,
h.run_date AS Run_Date ,
CAST(run_duration / 10000 AS VARCHAR(2)) + N'小时' + CAST(( run_duration - run_duration / 10000 * 10000 ) / 100 AS VARCHAR(2)) + N'分钟' + SUBSTRING(CAST(run_duration AS VARCHAR(10)),
LEN(CAST(run_duration AS VARCHAR(10))) - 1, 2) + N'秒' AS run_duration2,
j.name AS Job_Name ,
h.step_name AS Step_Name ,
h.run_status ,
h.message AS Message
FROM msdb.dbo.sysjobhistory h
LEFT JOIN msdb.dbo.sysjobs j
ON h.job_id = j.job_id
WHERE CONVERT(varchar(10),CAST((cast( h.run_date as varchar))AS date),121) = CONVERT(DATE,GETDATE())
AND h.step_id!=0
ORDER BY RunDateTime DESC