Wednesday, September 19, 2018

Change compatibility mode of a database automatically to match the version of the SQL Server Instance hosting the db

Do you have an environment where databases get restored onto your SQL Instances from different sources? If yes, you must have come across the fact that all the databases do not originate from the same version of SQL Server. If you have a SQL 2016 Instance, it is possible that databases get restored from different Instances on different versions such as SQL 2014, SQL 2012 etc. When such a move happens, the compatibility mode of the db needs to be changed to match the level of the Instance where it is being restored to (SQL 2016 in this case). If that not done, you are not letting the db make use of all the features of SQL 2016. 


What if that db creation process is constant? How do you keep up with automating the process of checking for any dbs with lower compatibility level and then change that to match the version of the SQL Instance? Below script does exactly that for you. You an automate the process by scheduling the below script as a SQL job that runs every day.



DECLARE @BUILD VARCHAR (MAX)=substring(CONVERT(VARCHAR(128), SERVERPROPERTY ('productversion')),1,2)+'0'
DECLARE @CMD VARCHAR(MAX)
--SET @CMD= (
SELECT @CMD = 'USE master;' + (
SELECT CHAR(10)+'ALTER DATABASE '+NAME+' set compatibility_level = '+@BUILD
from sys.databases
where database_id>4
AND compatibility_level <> @BUILD
              FOR XML PATH('')
              ) + CHAR(10)
--)
      
PRINT @CMD
EXEC (@CMD)

Tuesday, August 14, 2018

Detach all the user dbs on a SQL Instance



What do you do when you have to detach every single user database on a given SQL Instance? Isn’t it tedious to type the detach command for every single db? If you hate doing that, you came to the right place! Use the below script to generate the detach commands which can be executed to detach the dbs. When there are active spids in a database, the detach command is going to fail. One way around that is to kill all the connections in a database. I have got an even better option. You can set the database to offline mode which kills all the active connections forcefully, set it back to online immediately and then detach the db rightaway. That will kill the connections and detach the dbs in one shot.


set quoted_identifier off
declare @dbname varchar(100)
declare @string varchar(3000)
declare cursor1 cursor for
select name from sysdatabases where dbid>4
open cursor1
fetch next from cursor1 into @dbname
while (@@fetch_status = 0)
begin
select @string="use master
go
alter database "+@dbname +" set offline with rollback immediate
go
alter database "+@dbname +" set online
go
sp_detach_db "+@dbname +"
go"
print @string
fetch next from cursor1 into @dbname
end
close cursor1
deallocate cursor1


Friday, February 16, 2018

'No Transaction is active' error - MSDTC

When running a query using linked server connection, with the linked server target being in a different domain, you might encounter this issue

When the below query is run, the query would just complete successfully.

select top 10 * from [server\instance].master.sys.all_views with (nolock)

But when you embed the query in a distributed transaction, it throws an error message:

BEGIN DISTRIBUTED TRANSACTION;  
              select top 10 * from [server\instance].master.sys.all_views with (nolock) 
              COMMIT TRANSACTION;  
             

Below is the error message:

OLE DB provider "SQLNCLI11" for linked server "server\instance" returned message "No transaction is active.".
Msg 7391, Level 16, State 2, Line 2

The operation could not be performed because OLE DB provider "SQLNCLI11" for linked server "sf-rel-sql-03\h5rel04" was unable to begin a distributed transaction.

In my case, the source SQL Instance (where the query is being run) is a clustered Instance that runs on top of two physical nodes. The destination server is in a different domain. Because the Instance is clustered, the destination server is unable to resolve the MSDTC successfully. We have two options to resolve this issue:

1.     Cluster the MSDTC resource
2.     Add the physical nodes names to the hosts file in the below folder (on the server that is being referred to in the linked server connection)

c:\windows\system32\drivers\etc\hosts

Failed to obtain the resource handle for cluster resource with name or ID 'xxxxxxxxxxxxxxx' error on Availability Group databases

We recently had failures for our Backup Maintenance Plan (performing T-Log backups) and it would fail with the below error message: Message ...