SQL Server – Database Mail – “DatabaseMail process” log file messages

The following messages appear in your database mail log file every 10 minutes.

“DatabaseMail process is started”
“DatabaseMail process is shutting down”

Database Mail is set to shut down every 10 minutes by default and restart when emails are sent. On a busy server you might want to change this as follows.

Go to SSMS object browser, right click on the Database Mail icon, choose “view of change system parameters”, set new value in “Database Mail Executable Minimum Lifetime (seconds)”. Here’s how to calculate a value for 12 hours.


-- 60 seconds (as 1 minute) * 60 minutes (as 1 hour) * 12 hours
SELECT 60*60*12 AS ServiceUpTime

ServiceUpTime
-------------
43200

ScreenJot Cropped 08-27-2014 08 44 28

SQL Server – Monitor Blocking

Here’s how to write blocking messages out to the SQL Errorlog. It won’t look pretty but has everything you should need.


/*
Set up a trace to monitor blocking on a server.

*/

-- Trace locks into the Errolog file
DBCC TRACEON(1222, -1);
-- Check the status
DBCC TRACESTATUS (1222, -1)
-- and turn it off
DBCC TRACEOFF (1222,-1)

Here is a link which tells how to set up the SQL Profiler to monitor deadlocks using a Deadlock Graph. Choose “Save Deadlock XML Separately” in the new tab and “Each deadlock XML graph in a distinct file” as options and give it a path and filename. This way you can capture and read each lock easily, later.

Find any current locking … blocking for a particular database. I haven’t tried this.


/*

http://stackoverflow.com/questions/12422986/sql-query-to-get-the-deadlocks-in-sql-server-2008

*/

SELECT L.request_session_id AS SPID,
 DB_NAME(L.resource_database_id) AS DatabaseName,
 O.Name AS LockedObjectName,
 P.object_id AS LockedObjectId,
 L.resource_type AS LockedResource,
 L.request_mode AS LockType,
 ST.text AS SqlStatementText,
 ES.login_name AS LoginName,
 ES.host_name AS HostName,
 TST.is_user_transaction AS IsUserTransaction,
 AT.name AS TransactionName,
 CN.auth_scheme AS AuthenticationMethod
FROM sys.dm_tran_locks L
JOIN sys.partitions P
ON P.hobt_id = L.resource_associated_entity_id
JOIN sys.objects O
ON O.object_id = P.object_id
JOIN sys.dm_exec_sessions ES
ON ES.session_id = L.request_session_id
JOIN sys.dm_tran_session_transactions TST
ON ES.session_id = TST.session_id
JOIN sys.dm_tran_active_transactions AT
ON TST.transaction_id = AT.transaction_id
JOIN sys.dm_exec_connections CN
ON CN.session_id = ES.session_id
CROSS APPLY sys.dm_exec_sql_text(CN.most_recent_sql_handle) AS ST
WHERE resource_database_id = DB_ID()
ORDER BY L.request_session_id

SQL – Convert rows of single column data to one row of columns

Transform a single column of data to a single row of data one column per each original row. I needed to quote-comma delimit the columns too.


SELECT name
FROM sys.sysdatabases
WHERE name LIKE '%master%'
ORDER BY name

SELECT TOP 1
 STUFF((
 SELECT ', "' + name + '"'
 FROM sys.sysdatabases
 WHERE name LIKE '%master%'
 ORDER BY name
 FOR
 XML PATH('')
 ), 1, 1, '')
FROM sys.sysdatabases

/*
name
--------------------------------------------
master
master_admin
master_settings
--------------------------------------------
 "master", "master_admin", "master_settings"
*/

SQL Server – Using table variable to persist data within Transactions

This was a great idea taken from Three Really Handy Tricks With SQL Server Table Variables post.

1.Create a table variable @LOG which stores log text for each step and maybe some other key data about the step.
2.In each step, INSERT a row into @LOG.
3.When rollback occurs, INSERT another row in @LOG giving the reason for the rollback.
4.ROLLBACK
5.SELECT * FROM @LOG

All the code calling this batch has to do is interrogate the returned record set. If its last record is the one recording the ROLLBACK, then it knows something went wrong and can alert the user somehow, giving the full log of what happened. You cannot do this with a temporary table because temporary tables are transactional so the rollback will erase the log.

SQL Server – Script to Detach Attach Databases

This uses the old syntax.

SELECT DISTINCT
 DB_NAME(dbid) AS DatabaseName,
 fileid,
 CASE WHEN fileid = 1 THEN 'exec sp_detach_db ''' + DB_NAME(dbid) + ''';'
 ELSE ''
 END DetachScript,
 CASE WHEN fileid = 1
 THEN 'exec sp_attach_db @dbname = N''' + DB_NAME(dbid) + '''' + ',@filename' + CONVERT(VARCHAR(10), fileid) + '=N''' + filename + ''''
 ELSE ',@filename' + CONVERT(VARCHAR(10), fileid) + '=N''' + filename + ''''
 END AS AttachScript
FROM master.dbo.sysaltfiles
WHERE DATABASEPROPERTYEX(DB_NAME(dbid), 'Status') = 'ONLINE'
 AND DB_NAME(dbid) IN ('Sandbox')
ORDER BY DB_NAME(dbid),
 fileid
GO

SQL Transactions

A good article on implicit and explicit SQL Transactions:

Implicit transaction mode is not SQL Server’s default. You have to request implicit transaction mode either with a SET statement:

SET IMPLICIT_TRANSACTIONS ON;

That was from Did you Know? Nesting Transactions by Kalen Delaney.

-- Here's a full script to illustrate the behavior of @@trancount with implicit transactions:
SET IMPLICIT_TRANSACTIONS OFF;
GO
IF EXISTS ( SELECT *
 FROM sys.objects
 WHERE NAME = 'T1'
 AND type = 'U' )
 DROP TABLE T1;
GO
CREATE TABLE T1 (col1 INT);
GO
INSERT INTO T1
 SELECT 1;
GO

SET IMPLICIT_TRANSACTIONS ON;
GO
BEGIN TRAN;
 SELECT @@trancount;

UPDATE T1
 SET col1 = col1 + 1;
COMMIT TRAN;
SELECT @@trancount;

COMMIT TRAN;
SELECT @@trancount;
GO
SET IMPLICIT_TRANSACTIONS OFF;
GO

And more, On Transactions, errors and rollbacks from SQL in the Wild by Gail Shaw.

Msg 1934, Sev 16: UPDATE STATISTICS failed because the following SET options have incorrect settings: ‘ARITHABORT’.

Got this when I ran my sp__updatestats procedure in a SQL Agent jobstep, but it worked in Query Analyzer. The reason? The default settings are probably different in QA rather than external connections similar to SQL Agent.

Msg 1934, Sev 16: UPDATE STATISTICS failed because the following SET options have incorrect settings: 'ARITHABORT'. [SQLSTATE 42000]

The solution was to recreate the procedure that ran UPDATE STATISTICS using a SET command within the procedure. 

CREATE PROCEDURE dbo.sp__UpdateStats
AS
SET 
ARITHABORT ON 
SET 
QUOTED_IDENTIFIER ON 
...

We started to get this problem after I added a computed column to a table. 

Use COALESCE to put a column of data into a delimited list variable

Here’s an example of how to create a delimited list, using a field of rows of data and COALESCE.

CREATE TABLE #tmp (ID INT IDENTITY, Value VARCHAR(10))

INSERT #tmp (Value) VALUES(@@IDENTITY)
INSERT #tmp (Value) VALUES(@@IDENTITY)
INSERT #tmp (Value) VALUES(@@IDENTITY)
INSERT #tmp (Value) VALUES(@@IDENTITY)
INSERT #tmp (Value) VALUES(@@IDENTITY)
INSERT #tmp (Value) VALUES(@@IDENTITY)
INSERT #tmp (Value) VALUES(@@IDENTITY)
INSERT #tmp (Value) VALUES(@@IDENTITY)
INSERT #tmp (Value) VALUES(@@IDENTITY)
INSERT #tmp (Value) VALUES(@@IDENTITY)

DECLARE @vcList VARCHAR(100)
SELECT @vcList = COALESCE(@vcList + ‘;’, ”)
+ ISNULL(Value, ‘0’)
FROM #tmp

-- ORDER BY might not work
PRINT @vcList
Resulting in:
10;1;2;3;4;5;6;7;8;9

NOTE:
Don’t be surprised when ORDER BY doesn’t work.

‘SQL Server query processor builds an different execution plan when expressions are applied to columns in the query’s ORDER BY clause, than when those same expressions are applied to columns in the query’s SELECT list. The decision made by the query processor is based on the cost of possible execution plans.’