Rahman Agoro, the frontline SQL DBA

Just another WordPress.com weblog

Archive for August, 2010

Granting execute permissions to a database login permanently using db_executor role

Posted by rahmanagoro on August 30, 2010


I often find that some logins will need execute permissions to objects on the database, in some cases a development environment might exists where users dont have GUI interface to interact with the database, i.e every operation is all done through stored procedures. In such cases, it might be acceptable to grant execute permissions to all objects on the database.  

In SQL server the role db_datareader has always existed, but how come we don’t have a role called db_executor. In this blog, I will show you how you can create a custom role which gives execute permissions on stored procedures, functions on the database.  

For the purpose of demonstration I run the following scripts with SA privileges on the database  

--Create a database and a login named test, grant the test login read only access to the DEMO database
CREATE DATABASE [DEMO] ON  PRIMARY
( NAME = N'DEMO', FILENAME = N'C:\Database\DEMO.mdf' , SIZE = 3072KB , FILEGROWTH = 1024KB )
 LOG ON
( NAME = N'DEMO_log', FILENAME = N'C:\Database\DEMO_log.ldf' , SIZE = 1024KB , FILEGROWTH = 10%)
GO

USE [master]
GO
CREATE LOGIN [test] WITH PASSWORD=N'test', DEFAULT_DATABASE=[master], CHECK_EXPIRATION=OFF, CHECK_POLICY=OFF
GO
USE [DEMO]
GO
CREATE USER [test] FOR LOGIN [test]
GO
USE [DEMO]
GO
EXEC sp_addrolemember N'db_datareader', N'test'
GO

Whilst still logged in as myself, create objects under the DEMO database. 
 


use DEMO
GO
create table tblUser
(
UserID int identity(1,1),
UserName varchar(30)
)

insert into tblUser (UserName)
	Select 'Tom'
union
	Select 'Jen'

GO

Create procedure spGetUserName
as
select UserID, UserName
from tblUser

GO
exec spGetUserName

Now log on as the test user to the DEMO database and run the following scripts.  

 
select * from tblUser 
1 Tom
2 Jen 

Try executing the stored procedure we get the error below 
 
Msg 229, Level 14, State 5, Procedure spGetUserName, Line 1 
The EXECUTE permission was denied on the object ‘spGetUserName’, database ‘DEMO’, schema ‘dbo’. 
 
I can either grant execute permissions on this single stored procedure, but imagine that we had over a thousand stored procedures. One easy way to do this is to create a role and grant execute permission on the actual schema itself. 

use DEMO
go
CREATE ROLE [db_executor]
GO
GRANT EXECUTE ON SCHEMA ::dbo TO db_executor
GO
--Then we’ll add the Test user in the database to the db_executor role in the database:
USE DEMO
GO
EXEC sp_addrolemember N'db_executor', N'test'
GO

After running the above, we now execute the stored procedure and it executes fine without any problems. 

execute spGetUserName 

1 Tom
2 Jen

Posted in Day to day queries, Scripts, Security, SQL 2008, SQL Administration | Leave a Comment »

Changing collation setting on a SQL 2008 instance

Posted by rahmanagoro on August 28, 2010


It is possible to chang the collation setting on a database, but what happens if you try to change the collation setting on a SQL instance or on the system databases, for SQL 2008 this can be done from the command line. Generally, what i tend to do is as follows.

  1. I will find the location of all my databases, as changing the collation forces a mini re-installation and thus will detach all user databases and rebuild system databases.
select * from master..sysaltfiles

2      A full backup of system databases, msdb, master and model is also recomended. Changing collation will rebuild system databases.

Lets assume that the drive containing the SQL 2008 installation media is E:\

Follow the steps below from the command prompt


cd E:

Setup /QUIET /ACTION=REBUILDDATABASE /INSTANCENAME=MSSQLSERVER /SQLSYSADMINACCOUNTS="domain\username" /SAPWD= "London2012" /SQLCOLLATION=SQL_Latin1_General_CP1_CS_AS

 

The parameters are as follows, /SQLSYSADMINACCOUNTS this specifies the sysadmin account nominated.

/SAPWD = This is the SA password to be used afterwards.

Posted in Day to day queries, Scripts, SQL 2008, SQL Administration, Uncategorized | Leave a Comment »

SQL 2008 Installation step by step with pictures including silent unattended installation

Posted by rahmanagoro on August 28, 2010


SQL 2008 Manual Installation Guide

The following guide details how to install SQL 2008 step by step guide with pictures.

One important setting worth mentioning is collation setting, please ensure that you are using the right collation settings, the chosen database collation setting has been detailed is: SQL_Latin1_General_CP1_CS_AS .

Manual SQL Installation Steps

This page is for the SQL 2008 Installation steps.
Prerequisites To install SQL Server 2008

1. Insert the SQL Server installation media. From the root folder, double-click setup.exe. To install from a network share, locate the root folder on the share, and then double-click setup.exe. If the Microsoft SQL Server 2008 Setup dialog box appears, click OK to install the prerequisites, then click Cancel to exit SQL Server 2008 installation.
2. If the .NET Framework 3.5 SP1 installation dialog box appears, select the check box to accept the .NET Framework 3.5 SP1 License Agreement. ClickNext. To exit SQL Server 2008 installation, click Cancel. When installation of .NET Framework 3.5 SP1 is complete, click Finish.
3. Windows Installer 4.5 is also required, and might be installed by the Installation Wizard. If you are prompted to restart your computer, restart it, and then restart SQL Server 2008 setup.exe

Carry on with the following steps.

Click on show details and ensure that all the checks are passed.

Select all the features for installation

Select the root directory for the installation.

Check disk space summary.

Select the account details for provisioning the SQL service and other related services.

Select the collation setting for the installation, note the collation setting in use here.

Select Authentication mode, if mixed authentication is used, select the SA password.

Select a directory for the database.

Select the filestream option if applicable.

Select the Analysis services account configuration.

Select the directory for the Analysis service related files.

Select reporting services configuration.

Select error reporting options.

Ensure that installation rules are all passed.

Installation screen, the process will take some time, this depends on the capacity of the machine on which it is being installed on to.


After a successfull installation, open up Programs >> SQL Server 2008 >> Configuration Tools >> SQL Server Configuration Manager

Check the TCP/IP section and enable it.

Click on Enable.

SQL 2008 Scripted Installation

 

Use the command line options below to install SQL 2008, remember to change the directory to the directory where the installation media is.
Setup.exe /QUIET /QS /ACTION=Install /ERRORREPORTING=1 /SAPWD=”******” /SQLSVCPASSWORD=”****” /AGTSVCPASSWORD=”****” /ASSVCPASSWORD=”****” /ISSVCPASSWORD=”****” /RSSVCPASSWORD=”******” /ConfigurationFile=C:\Downloads\Config.ini
Attention should also be paid to the configuration file as well, see attached configuration file which contains answers for the installation.
Install SQL 2008 SP1 Quietly
You can install SQL 2008 SP1 quietly without the need for a reboot, just ensure that you close all Management Studio windows that are open, this way a reboot will most likely not be required. Use the attached batch file, ensure that you have downloaded the service pack and change the path referenced in the batch file to the correct path.

Configuration.ini file

Below is a sample configuration.ini file for the installation above, copy it and save it to  a file called Config.ini as referenced above in the command line installation.


;SQLSERVER2008 Configuration File
[SQLSERVER2008]

; Specify the Instance ID for the SQL Server features you have specified. SQL Server directory structure, registry structure, and service names will reflect the instance ID of the SQL Server instance.

INSTANCEID="MSSQLSERVER"

; Specifies a Setup work flow, like INSTALL, UNINSTALL, or UPGRADE. This is a required parameter.

ACTION="Install"

; Specifies features to install, uninstall, or upgrade. The list of top-level features include SQL, AS, RS, IS, and Tools. The SQL feature will install the database engine, replication, and full-text. The Tools feature will install Management Tools, Books online, Business Intelligence Development Studio, and other shared components.

FEATURES=SQLENGINE,REPLICATION,FULLTEXT,AS,RS,BIDS,CONN,IS,BC,SDK,BOL,SSMS,ADV_SSMS,SNAC_SDK,OCS

; Displays the command line parameters usage

HELP="False"

; Specifies that the detailed Setup log should be piped to the console.

INDICATEPROGRESS="False"

; Setup will not display any user interface.

QUIET="False"

; Setup will display progress only without any user interaction.

QUIETSIMPLE="False"

; Specifies that Setup should install into WOW64. This command line argument is not supported on an IA64 or a 32-bit system.

X86="False"

; Specifies the path to the installation media folder where setup.exe is located.

MEDIASOURCE="I:\"

; Specify if errors can be reported to Microsoft to improve future SQL Server releases. Specify 1 or True to enable and 0 or False to disable this feature.

ERRORREPORTING="False"

; Specify the root installation directory for native shared components.

INSTALLSHAREDDIR="C:\Program Files\Microsoft SQL Server"

; Specify the installation directory.

INSTANCEDIR="C:\Program Files\Microsoft SQL Server"

; Specify that SQL Server feature usage data can be collected and sent to Microsoft. Specify 1 or True to enable and 0 or False to disable this feature.

SQMREPORTING="False"

; Specify a default or named instance. MSSQLSERVER is the default instance for non-Express editions and SQLExpress for Express editions. This parameter is required when installing the SQL Server Database Engine (SQL), Analysis Services (AS), or Reporting Services (RS).

INSTANCENAME="MSSQLSERVER"

; Agent account name

AGTSVCACCOUNT="NT AUTHORITY\SYSTEM"

; Auto-start service after installation.

AGTSVCSTARTUPTYPE="Manual"

; Startup type for Integration Services.

ISSVCSTARTUPTYPE="Automatic"

; Account for Integration Services: Domain\User or system account.

ISSVCACCOUNT="NT AUTHORITY\SYSTEM"

; The name of the account that the Analysis Services service runs under.

ASSVCACCOUNT="NT AUTHORITY\SYSTEM"

; Controls the service startup type setting after the service has been created.

ASSVCSTARTUPTYPE="Automatic"

; The collation to be used by Analysis Services.

ASCOLLATION="Latin1_General_CS_AS"

; The location for the Analysis Services data files.

ASDATADIR="C:\Program Files\Microsoft SQL Server\MSAS10.MSSQLSERVER\OLAP\Data"

; The location for the Analysis Services log files.

ASLOGDIR="C:\Program Files\Microsoft SQL Server\MSAS10.MSSQLSERVER\OLAP\Log"

; The location for the Analysis Services backup files.

ASBACKUPDIR="C:\Program Files\Microsoft SQL Server\MSAS10.MSSQLSERVER\OLAP\Backup"

; The location for the Analysis Services temporary files.

ASTEMPDIR="C:\Program Files\Microsoft SQL Server\MSAS10.MSSQLSERVER\OLAP\Temp"

; The location for the Analysis Services configuration files.

ASCONFIGDIR="C:\Program Files\Microsoft SQL Server\MSAS10.MSSQLSERVER\OLAP\Config"

; Specifies whether or not the MSOLAP provider is allowed to run in process.

ASPROVIDERMSOLAP="1"

; Specifies the list of administrator accounts that need to be provisioned.

ASSYSADMINACCOUNTS="DOMAIN\username"

; Startup type for the SQL Server service.

SQLSVCSTARTUPTYPE="Automatic"

; Level to enable FILESTREAM feature at (0, 1, 2 or 3).

FILESTREAMLEVEL="3"

; Name of Windows share to be created for FILESTREAM File I/O.

FILESTREAMSHARENAME="MSSQLSERVER"

; Set to "1" to enable RANU for SQL Server Express.

ENABLERANU="False"

; Specifies a Windows collation or an SQL collation to use for the Database Engine.

SQLCOLLATION="SQL_Latin1_General_CP1_CI_AS"

; Account for SQL Server service: Domain\User or system account.

SQLSVCACCOUNT="NT AUTHORITY\SYSTEM"

; Windows account(s) to provision as SQL Server system administrators.

SQLSYSADMINACCOUNTS="Domain\username"

; The Database Engine root data directory.

INSTALLSQLDATADIR="C:\Database"

; Default directory for the Database Engine backup files.

SQLBACKUPDIR="C:\Database"

; Default directory for the Database Engine user databases.

SQLUSERDBDIR="C:\Database"

; Directory for Database Engine TempDB files.

SQLTEMPDBDIR="C:\Database"

; Provision current user as a Database Engine system administrator for SQL Server 2008 Express.

ADDCURRENTUSERASSQLADMIN="False"

; Specify 0 to disable or 1 to enable the TCP/IP protocol.

TCPENABLED="0"

; Specify 0 to disable or 1 to enable the Named Pipes protocol.

NPENABLED="0"

; Startup type for Browser Service.

BROWSERSVCSTARTUPTYPE="Disabled"

; Specifies which account the report server NT service should execute under.  When omitted or when the value is empty string, the default built-in account for the current operating system.
; The username part of RSSVCACCOUNT is a maximum of 20 characters long and
; The domain part of RSSVCACCOUNT is a maximum of 254 characters long.

RSSVCACCOUNT="NT AUTHORITY\SYSTEM"

; Specifies how the startup mode of the report server NT service.  When
; Manual - Service startup is manual mode (default).
; Automatic - Service startup is automatic mode.
; Disabled - Service is disabled

RSSVCSTARTUPTYPE="Automatic"

; Specifies which mode report server is installed in.
; Default value: “FilesOnly”

RSINSTALLMODE="DefaultNativeMode"

Posted in Day to day queries, Professional Development, SQL 2008, SQL Administration, Uncategorized | 1 Comment »

Script out SQL agent jobs from powershell

Posted by rahmanagoro on August 26, 2010


At my shop, we currently use SVN to store database objects, one object type which is often overlooked is SQL agent jobs, I needed a way in which I can generate sql agent jobs into sql files, SQL management studio allows you to script jobs, but you can either do this one at a time, or script all the jobs in one big file. The two options are not really ideal for me, the reason being that I may choose to be selective about which jobs I install on a server, other jobs are installed as part of an installation suite, e.g management data warehouse in SQL 2008.

I have written a simple powershell script that will simple script out all SQL agent jobs, one might have multiple servers, I have made the script such that it reads a text file for a list of servers, simply save this file on a location and call the powershell script, you also need to specify where you want the script to be generated to as well.


#Original
# Load SMO extension

[System.Reflection.Assembly]::LoadWithPartialName("Microsoft.SqlServer.Smo") | Out-Null;
# Get List of sql servers to check

#$sqlservers = Get-Content "$Env:USERPROFILE\sqlservers.txt";
$sqlservers = Get-Content "C:\Servers.txt";

# Loop through each sql server from sqlservers.txt
foreach($sqlserver in $sqlservers)

{

      # Create an SMO Server object
      $srv = New-Object "Microsoft.SqlServer.Management.Smo.Server" $sqlserver;

      # Jobs counts
      $totalJobCount = $srv.JobServer.Jobs.Count;
      $failedCount = 0;
      $successCount = 0;

      # For each jobs on the server
      foreach($job in $srv.JobServer.Jobs)

      {
            # Default write colour
            $colour = "Green";
            $jobName = $job.Name;
            $jobEnabled = $job.IsEnabled;
            $jobLastRunOutcome = $job.LastRunOutcome;
 			$jobNameFile = "C:\SQLJOBS\" + $jobName+".sql"

 			Write-Host $job.Name
			Write-Host "The location of the file is called " $jobNameFile

#			[System.Reflection.Assembly]::LoadWithPartialName("Microsoft.SqlServer.Smo") | Out-Null
#			$srv = New-Object "Microsoft.SqlServer.Management.Smo.Server" $sqlserver
#			#$srv.JobServer.Jobs | foreach {$_.Script()} | out-file -path $path
			$job | foreach {$_.Script()} | out-file $jobNameFile

            # Set write text to red for Failed jobs
            if($jobLastRunOutcome -eq "Failed")

            {

                  $colour = "Red";
                  $failedCount += 1;
            }

            elseif ($jobLastRunOutcome -eq "Succeeded")
            {
                  $successCount += 1;
            }

            Write-Host -ForegroundColor $colour "SERVER = $sqlserver JOB = $jobName ENABLED = $jobEnabled LASTRUN = $jobLastRunOutcome";
      }

      # Writes a summary for each SQL server
      Write-Host -ForegroundColor red "=========================================================================================";
      Write-Host -ForegroundColor red "$sqlserver total jobs = $totalJobCOunt, success count $successCount, failed jobs = $failedCount.";
      Write-Host -ForegroundColor red "=========================================================================================";
}

Posted in Day to day queries, Powershell, Professional Development, Scripts, SQL 2008, Tips | 4 Comments »

Searching for objects in a database views stored procedures functions etc etc

Posted by rahmanagoro on August 26, 2010


I am often faced with the need to search for objects on a database, for example i want to ensure that there are no other objects referencing the objects, or perhaps I need to change the schema of a table, but want to make sure that I capture and edit all other objects that rely on the object i.e a table.

In one example, I noticed an application was using custom key generation for generating a unique ID, this was causing a deadlock on the database, and I pinned down the problem to a exclusive lock being held on the table during another update, whilst a new key was being generated.

select @myID = max([ID])  + 1 from Company.dbo.tbluser

In order to complete regression testing, I need to ensure that all objects making reference to the table were correctly identified and the code changed.

EXEC sp_MSforeachdb 
'if ''?''  ''master'' and ''?''  ''tempdb''and ''?''  ''model''and ''?''  ''msdb''and ''?''  ''distribution''
begin
select ''Finding the use of tbluser on database '' ?
Use ?

Select 
DISTINCT OBJECT_NAME(A.id), B.type
from syscomments A
join sysobjects B
on A.id = B.id
where A.text like ''%tbluser%''
or text like ''% INSERT tbluser %''
order by OBJECT_NAME(A.id), B.type
end
'

In the example below, I was looking for any object across the database that use the COLLATE or collate hint, as the database server was case sensitive, I have to try both lower and upper case.

EXEC sp_MSforeachdb 
'if ''?''  ''master'' and ''?''  ''tempdb''and ''?''  ''model''and ''?''  ''msdb''and ''?''  ''distribution''
begin
select ''Finding the use of collate on DB '' ?
Use ?

Select 
DISTINCT OBJECT_NAME(A.id), B.type
from syscomments A
join sysobjects B
on A.id = B.id
where A.text like ''%collate%''
or text like ''%%COLLATE%''
order by OBJECT_NAME(A.id), B.type
end
'

Posted in Day to day queries, Scripts, SQL 2008 | Leave a Comment »

DBA and Developer relationship

Posted by rahmanagoro on August 26, 2010


Throughout my career as a DBA, I often find that I need to work with developers more closely than anyone can imagine, DBA’s are often thought about as the middle man between the development team and also system administrators. I find that this is often the case, the DBA is a special position within any organization, responsible for the day to day maintenance and smooth running of the database involves being patient, responsive, being communicative with your customers (developers, business users, management, system administrators and other stake holders). Personally I tend to have a good rapport with developers, as they would often know how the database objects interact with the application, especially within a shop with little or no documentation.

I also find that although, as a DBA one doesn’t really have to know the application or business inside out, but it does help if you do. There was an occasion where an analyst complained about slow performance of the application, if users complain about slow performance within applications, as a DBA there are many lines of enquiries to make, some of which are not limited to the following:

  • Locking on the database
  • Improper use of indexes on the database
  • Statistics which are not up to date.
  • Inappopriate query plans
  • Heavy IO operation on the database, this can be heavy reporting/ad-hoc queries or perhaps backups running on the system.

In my own case, I was able to speak to the developer, a profiler trace was created to see what the problem was. It was later tracked down to a stored procedure using an in appropriate query plan. I was able to speak to the developer who quickly pointed out to me the stored procedure that was being called for the functionality the user was trying to use. This was subsequently fixed and the user was able to carry on using the application.

My tips are as follows

Speak to developers about applications that they are working with, especially ones which interact with the database. This way, you have an idea of what sort of things to watch out for.

Always see your developers as your customers as well, a healthy relationship with your developers means that both sides can work together as a team, and thus improving the service being offered to the organization.

Don’t think your developers will always come and ask you questions, at first the trust may not be there, that’s why its good to have a good report and make sure they are comfortable with you.

Be diplomatic when you see bad SQL code, don’t say to developers “your code is really horrible, I don’t know how you got the job ! “, be diplomatic and try and help them write better queries, this way when they are not comfortable with writing SQL code or a code which is not performing, they are willing to seek your help as the DBA, instead of just releasing it on to the production database server.

Socialize with the team !

Posted in Day to day queries, Professional Development | Leave a Comment »

SQL 2008 replication error ” retrying command or the process is running and waiting for a response from the server “

Posted by rahmanagoro on August 26, 2010


I was working with SQL 2008 replication and on checking replication monitor, I noticed that on the distribution agent for one of the databases, it had a retrying command status. I further looked into it to see what the problem was, here I can see that the distribution agent had become stucked whilst trying to send commands to the subscriber. The first thing that came to my mind was, “what is happening with the subscriber ? ”


I ran the following on the subscriber

use  master
 GO
 sp_who2 active

I was able to see that there is a blocking spid at the moment, which is coming from my distributor. So what must have happened here is that, as a snapshot was being delivered to the subscriber, objects such as stored procedures and functions were also being delivered as well, thereby causing a deadlock to occur.

To confirm this, I ran the code below to check for replication errors.

select * from distribution..MSrepl_errors

I had entries like

1092 2010-08-01 00:35:16.560 0 0 MSSQL_ENG HYT00 Query timeout expired 0x0001262200000210000100000002 1 0

1092 2010-08-01 00:35:16.557 0 1 MSSQL_ENG if @@trancount > 0 rollback tran 0x0001262200000210000100000002 1 0

On the subscriber, I confirmed the locking scenario by looking at the wait type for the replication SPID, and it was a LCK_M_S wait type, which confirmed it was a deadlocking situation.

I also ran a deadlocking detail script as well.

SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED

SELECT
 owt.session_id AS waiting_session_id,
 DB_NAME(tls.resource_database_id) AS database_name,
 owt.wait_duration_ms,
--    owt.waiting_task_address,
 owt.wait_type,
--    tls.resource_associated_entity_id,
--    tls.resource_description AS local_resource_description,
 tls.resource_type,
 (CASE tls.resource_type
 WHEN 'OBJECT' THEN OBJECT_NAME(tls.resource_associated_entity_id, tls.resource_database_id)
 WHEN 'DATABASE' THEN DB_NAME(tls.resource_database_id)
 ELSE (SELECT  OBJECT_NAME(pat.[object_id], tls.resource_database_id)
 FROM sys.partitions pat WHERE pat.hobt_id = tls.resource_associated_entity_id)

 END
 ) AS object_name,
 tls.request_mode,
 tls.request_type,
 tls.request_session_id,
 owt.blocking_session_id,
 owt.resource_description AS blocking_resource_description,
 (SELECT SUBSTRING(est.[text], ers.statement_start_offset/2 + 1,
 (CASE WHEN ers.statement_end_offset = -1
 THEN LEN(CONVERT(nvarchar(max), est.[text])) * 2
 ELSE ers.statement_end_offset
 END
 - ers.statement_start_offset
 ) / 2)
 FROM sys.dm_exec_sql_text(ers.[sql_handle]) AS est) AS waiting_query_text,
 CASE WHEN owt.blocking_session_id > 0
 THEN (
 SELECT
 est.[text] FROM sys.sysprocesses AS sp
 CROSS APPLY sys.dm_exec_sql_text(sp.[sql_handle]) as est
 WHERE sp.spid = owt.blocking_session_id)
 ELSE
 NULL
 END AS blocking_query_text,
 qp.query_plan AS waiting_query_plan
FROM sys.dm_tran_locks AS tls
 INNER JOIN sys.dm_os_waiting_tasks owt ON tls.lock_owner_address = owt.resource_address
 INNER JOIN sys.dm_exec_requests ers ON tls.request_request_id = ers.request_id AND owt.session_id = ers.session_id
 OUTER APPLY sys.dm_exec_query_plan(ers.[plan_handle]) AS qp
GO


I was able to see that one spid was calling the stored procedure:

exec sp_MSacquiresnapshotdeliverysessionlock

and the other spid only had a begin tran statement showing from my dbcc inputbuffer statement.
I killed this SPID which had begin tran as the sql statement which it was running, and the replication commands were delivered and replication was working once more. The problem was fixed.

Posted in SQL 2008, SQL Administration, SQL replication, Uncategorized | 2 Comments »

Powershell secret timeout ! Running SQL from powershell V1

Posted by rahmanagoro on August 26, 2010


I have always been very keen to learn new aspects of SQL server and as much as possible use new technology. When SQL 2008 came out about 2 years ago, powershell technology has always been one that’s interests me, I like the fact that almost any task can now be scripted. I liked the fact that, I can write a script and push it out to as many SQL instances as possible. I also like the fact that tasks in windows can also be scripted as well, so lets say I want to collect perfmon data and integrate this with SQL server, it is now easy to achieve this.

To this note, I was inclined to use powershell towards running backup stored procedures, although I could have easily used TSQL to do this, but as I know, powershell is the future and as a DBA, I don’t want to be left behind. I also liked the fact that, within my backup scripts I want to delete older backups after they have been backed up to tape, powershell allows me to easily do this without having to write lines of scripts.

I found a sample scripts on:

To my surprise, I started to run my powershell scripts which backs up SQL databases via stored procedures, all of a sudden they started failing. The stored procedure was fairly straight forward and simple, but yet the scripts will still fail. What I noticed was that for differential backups, the powershell script runs fine, but for full backups the powershell scripts which calls the stored procedure fails. This occurred to me like some kind of issue with timeout, at first it sounded strange as I didn’t specify a timeout period, but yet the query was failing.

Even a simple query like the one below will fail as well

$SqlConnection = New-Object System.Data.SqlClient.SqlConnection
$SqlConnection.ConnectionString = "Server=localhost;Database=master;Integrated Security=True"
$SqlCmd = New-Object System.Data.SqlClient.SqlCommand
$SqlCmd.CommandText = "  waitfor delay '00:00:50'"
$SqlCmd.Connection = $SqlConnection
$SqlAdapter = New-Object System.Data.SqlClient.SqlDataAdapter
$SqlAdapter.SelectCommand = $SqlCmd
$DataSet = New-Object System.Data.DataSet
$SqlAdapter.Fill($DataSet)
$SqlConnection.Close()
$DataSet.Tables[0]


I later confirmed from Microsoft MVP Grant Fitchley that there is a 30 second default timeout, this is something that everybody should be aware of in order to avoid this problem. I also note that a connect ticket has been opened for this bug, see https://connect.microsoft.com/PowerShell/feedback/details/523996/invoke-sqlcmd-querytimeout?wa=wsignin1.0

As a workaround, a timeout value was passed into the connection properties.
If a timeout value of 0 is specified, then the script will not time out.

$SqlConnection = New-Object System.Data.SqlClient.SqlConnection
$SqlConnection.ConnectionString = "Server=localhost;Database=master;Integrated Security=True"
$SqlCmd = New-Object System.Data.SqlClient.SqlCommand
$SqlCmd.CommandText = " waitfor delay '00:00:35'"
$SqlCmd.Connection = $SqlConnection
$SqlCmd.CommandTimeout = 0
$SqlAdapter = New-Object System.Data.SqlClient.SqlDataAdapter
$SqlAdapter.SelectCommand = $SqlCmd
$DataSet = New-Object System.Data.DataSet
$SqlAdapter.Fill($DataSet)
$SqlConnection.Close()
$DataSet.Tables[0]

Posted in Powershell, SQL 2008, SQL Administration | Leave a Comment »