Wednesday, October 19, 2016

Getting Perfmon Data

In so many of the SQL Server instances I manage, getting to the console isn't possible (or isn't advisable) and having the ability to get these things via SQL is a great help.


To do that, we can grab a quick select like this, to see the various counters available:


  1. select *
  2. from sys.dm_os_performance_counters



For example, if I wanted to monitor how many user connections I had throughout the day, I could save the results of the query below to a monitoring table.


  1. select *
  2. from sys.dm_os_performance_counters
  3. where object_name = 'MSSQL$WORLDWIDE:General Statistics'
  4. and counter_name = 'User Connections';

Tuesday, October 11, 2016

Creating a stored proc in every database

So, the other day, I needed to create a stored procedure in every database. This is what I came up with.


First, we need to make a test set of simple, empty databases:

  1. use master;
  2. go
  3.  
  4. create database CreateSPTest1;
  5. create database CreateSPTest2;
  6. create database CreateSPTest3;
  7. create database CreateSPTest4;
  8. create database CreateSPTest5;
  9. go

Now, here was my first pass at writing a simple loop to get an object created in the target databases.

  1. declare @currentDB sysname;
  2. declare @sqlToRun nvarchar(max);
  3. declare LoopDBs cursor for
  4. select [name] from sys.databases where name like '%SPTest%';
  5. open LoopDBs;
  6. fetch next from LoopDBs into @currentDB;
  7. while @@FETCH_STATUS = 0
  8. begin
  9. set @sqlToRun = '';
  10. set @sqlToRun = 'USE ' + @currentDB + '; create table t1(c1 int);';
  11. --print @sqlToRun;
  12. exec sp_executesql @sqltorun;
  13. fetch next from LoopDBs into @currentDB;
  14. end
  15. close LoopDBs;
  16. deallocate LoopDBs;
  17. GO



Next, I wanted to extend my loop, above, to create an uber-simple stored procedure in every database. Here's where I hit my first roadblock. No matter what I seemed to, I received an error that looked like this:

Msg 111, Level 15, State 1, Procedure usp1, Line 1 [Batch Start Line 36]
'CREATE/ALTER PROCEDURE' must be the first statement in a query batch.

For what it's worth, here's the loop I was using. As you'll see, the only difference between this and the snippet above is the set @sqlToRun variable.

  1. declare @currentDB sysname;
  2. declare @sqlToRun nvarchar(max);
  3. declare LoopDBs cursor for
  4. select [name] from sys.databases where name like '%SPTest%';
  5. open LoopDBs;
  6. fetch next from LoopDBs into @currentDB;
  7. while @@FETCH_STATUS = 0
  8. begin
  9. set @sqlToRun = '';
  10. set @sqlToRun = 'USE ' + @currentDB + '; create proc usp1 as select getdate();';
  11. --print @sqlToRun;
  12. exec sp_executesql @sqltorun;
  13. fetch next from LoopDBs into @currentDB;
  14. end
  15. close LoopDBs;
  16. deallocate LoopDBs;
  17. GO



Lastly, this is what I came up with after a quick Google-Fu. In short, I found that sp_executesql calls can be nested, and, if the first call to sp_executesql contains the USE statement, then the second will operate against the proper database.


  1. declare @currentDB sysname;
  2. declare @sqlToRun nvarchar(max);
  3. declare @sqlForInside nvarchar(max);
  4. declare @params nvarchar(4000);
  5. set @params = '@sqlToRunInside nvarchar(max)';
  6. declare LoopDBs cursor for
  7. select [name] from sys.databases where name like '%SPTest%';
  8. open LoopDBs;
  9. fetch next from LoopDBs into @currentDB;
  10. while @@FETCH_STATUS = 0
  11. begin
  12. set @sqlForInside = 'create proc usp1 as select getdate();';
  13. --print @sqlToRun;
  14. set @sqlToRun = '';
  15. set @sqlToRun = 'USE ' + @currentDB + '; exec sp_executesql @sqlToRunInside';
  16. exec sp_executesql @sqltorun, @params, @sqlToRunInside = @sqlForInside;
  17. fetch next from LoopDBs into @currentDB;
  18. end
  19. close LoopDBs;
  20. deallocate LoopDBs;
  21. GO