Every year, PowerShell increases its stranglehold on the Windows Server system and the applications that run upon it – with good reason too. Its consistent mechanisms for interaction between its scripting interface and the underlying systems make it easy for people to feel comfortable, and there is a discoverability that has been lacking in many other scripting environments.
Of course, SQL Server hasn’t been overlooked at all, and it’s coming up to five years since the SnapIns were made available (even longer since people started to dabble with SQL using PowerShell).
But what’s going on behind the scenes? Does PowerShell present a threat to those amongst us who will always prefer T-SQL? Does PowerShell give us new options that are not available any other way? Well, let’s have a bit of a look, especially since this month’s T-SQL Tuesday (hosted by Wayne Sheffield who tweets as @DBAWayne) is on the topic of PowerShell.
So we know PowerShell is useful. However we spin it up, we can quickly jump into writing commands, whether it be interacting with WMI, hooking into some .Net assembly we’ve loaded up, or simply browsing the file system. I’ve developed a tendency to use it to start whichever SQL instances I’m needing for the day – by default I have all of them turned off, since I don’t know which one I’ll be wanting most.
If we’re going to be interacting with SQL, then it’s easiest to either load up the SQLPS environment directly (there’s a PowerShell shortcut within Management Studio), or else (as I do), start a PowerShell window with the Snapin loaded. I prefer this later option, as the SQLPS environment is a slightly cut-back version of PowerShell. But either way – the stuff I’ll continue on with is essentially the same whichever environment you use.
If you’ve talked about SQL with me long enough, you’ll have come across the fact that I often use SQL Profiler when I’m curious about where to find information. My former colleague Jim McLeod (@Jim_McLeod) blogged about this a few months ago, with an example that I remember looking through with him four or five years ago. It’s a great technique that works on all kinds of things, even across different versions of SQL Server. It also adds as a terrific reminder that Management Studio is not a special application, it simply knows how to ask for the pieces of information that it shows.
But PowerShell (or SMO, for that matter), that’s in the .Net world. Surely that would be able to bypass the clunky T-SQL stuff that Management Studio does… I mean, Management Studio has to be flexible enough to work across remote servers, talking through firewalls that only allow T-SQL interfaces. Surely PowerShell has access to a deeper magic.
Well, no. PowerShell still lets you talk to remote servers, and ends up using the same methods.
Let’s prove it.
Spin up Profiler, and start a trace against your favourite instance. I like to watch for SQL:BatchCompleted, SP:StmtCompleted and RPC:Completed events when doing this kind of thing. I’m using an instance that isn’t doing anything else, but you could apply a ColumnFilter to filter the events to things with an ApplicationName starting with SQLPS if you prefer.
With that running, I jump into PowerShell and do something like:
1 |
PS SQLSERVER:\sql\localhost\sql2008r2> dir Databases | ft name |
This lists the names of the databases on my SQL2008R2 instances. You don’t need to see the results, you can imagine them for yourself.
If PowerShell were using some secret interface, it’s unlikely we’d see something in Profiler. But it’s not, and we see a bunch of stuff.
We see a bunch of Remote Procedure Calls, each with a Stored Procedure Statement Completed event showing the same information. And look – we see queries against master.sys.databases, asking for the name of each of the databases, passing in the name as a parameter. Brilliant! Notice just a bit earlier though, there’s a SQL:BatchCompleted call. This means that a query has been passed in directly. It’s this:
1 |
SELECT CAST( serverproperty(N'Servername') AS sysname) AS [Server_Name], dtb.name AS [Name] FROM master.sys.databases AS dtb WHERE (CAST(case when dtb.name in ('master','model','msdb','tempdb') then 1 else dtb.is_distributor end AS bit)=0) ORDER BY [Name] ASC |
So it grabs the list of database names first, and then makes extra calls to be able to fetch the list of names again, one by one.
The reason why it’s grabbing the list of names one by one isn’t because it’s stupid and is asking to be ridiculed. It’s because we’ve asked to see that property, and I guess the PowerShell people figured that no matter what property you ask for, it’ll go and fetch it to show you.
When I asked for the CompatibilityLevel property instead, I got some different rows thrown in. Interestingly though, it still asked for the name each time.
Also interestingly, when I asked for the CompatibilityLevel a subsequent time, the calls for “SELECT dtb.compatibility_level…” weren’t in there. They’d been cached by the PowerShell environment – important to note if you ever come across PowerShell giving you old values.
So what about asking something more interesting? Let’s try asking about the IndexSpaceUsage in AdventureWorks.
1 |
PS SQLSERVER:\sql\localhost\sql2008r2> gi Databases\AdventureWorks | ft IndexSpaceUsage |
The result tells me it’s 62576. Yeah, but today I’m not interested in that, just what happened in the trace.
Four entries. An SP:StmtCompleted with matching RPC:Completed, and two SQL:BatchCompleted.
The SP:StmtCompleted and RPC:Completed were this statement, passing in the parameter value ‘AdventureWorks’. Clearly incredibly informative.
1 |
SELECT CAST(0 AS float) AS [IndexSpaceUsage], dtb.name AS [DatabaseName] FROM master.sys.databases AS dtb WHERE (dtb.name=@_msparam_0) |
This is getting the value zero. Wow. Brilliant stuff.
The last entry – the second of the two SQL:BatchCompleted events is:
1 |
select convert(float,low/1024.) from master.dbo.spt_values where number = 1 and type = 'E' |
If you run this in Management Studio, you’ll discover it gives the value 8. Ok.
The other entry is more interesting.
1 2 |
use [AdventureWorks] SELECT SUM(CASE WHEN a.type <> 1 THEN a.used_pages WHEN p.index_id &amp;lt; 2 THEN a.data_pages ELSE 0 END) AS [DataSpaceUsage], SUM(a.used_pages) AS [IndexSpaceTotal] FROM sys.allocation_units AS a INNER JOIN sys.partitions AS p ON (a.type = 2 AND p.partition_id = a.container_id) OR (a.type IN (1,3) AND p.hobt_id = a.container_id) |
This is more like it! We run this in Management Studio, and we see two values. DataSpaceUsage is 13682, IndexSpaceTotal is 21504. Neither are our value 62576. But we do have clues in the column names, and in that value 8 that came back too. We can easily deduce that it’s actually (IndexSpaceTotal-DataSpaceUsage)*8, and we have ourselves a nice little method for working out the IndexSpaceUsage ourselves now if we need it.
Or we can just ask PowerShell next time as well.
Incidentally – if you’re considering doing the MCM Lab exam some time, then you might find that a familiarity with PowerShell comes in really handy. I’m not saying there are PowerShell questions on the exam at all – I’m just suggesting that you may find that PowerShell becomes a really useful way of getting at some of the information that you’re looking for. If you’re stumbling around the list of DMVs trying to remember which one it is that stores some particular thing, remember that you might be able to get the data out more easily if you use PowerShell instead.
So can we discover secret things about SQL from PowerShell? Are there things we can do in PowerShell that are impossible through other mechanisms? Hooks that let us break the rules even?
Recently, Kendal van Dyke asked a question about this kind of thing on Twitter. He was wondering if you could have a default constraint on a column in a view. The reason for his wondering was that he saw a property on a view column in PowerShell that made him wonder. The answer is no though, and there’s a simple reason.
PowerShell is a programmatic interface. It involves classes and property and methods. It does things row by row, which is why much of what you see in that trace feels amazingly pedantic – asking about things which shouldn’t have to be that complicated. The implication of this though, is that PowerShell reuses the concept of a column, regardless of whether this is a column in a table, a view, or anywhere else it decides to need a column. The fact that columns in tables have some extra properties isn’t enough to make this class re-use pointless. If we try to set a Default constraint for a column in a view though, we get an error, just like if we tried to do it any other way.
The PowerShell I used was:
1 |
$db = Get-Item SQLSERVER:\sql\localhost\sql2008r2\Databases\AdventureWorks $def = New-Object -TypeName Microsoft.SqlServer.Management.SMO.Default –ArgumentList $db, 'ViewDefault'; $def.TextHeader = 'CREATE DEFAULT ViewDefault AS' $def.TextBody = 'ABC' $def.Create() $def.BindToColumn('vStateProvinceCountryRegion','StateProvinceCode','Person') |
The code that ended up getting called was to the stored procedure sp_bindefault (despite it being deprecated). Naturally, trying to execute this against a view column gives an error regardless of what wrappers you have put around it – PowerShell or not.
So PowerShell is very useful, and it provides a handy way of getting to a lot of things that could be otherwise hard. But looking below the surface, it isn’t able to circumvent the basic restrictions of SQL Server, because it still ends up doing its work using T-SQL.
This Post Has 6 Comments
This is all interesting, but, at the risk of being a bit pedantic, I ought to say that your criticisms of PowerShell should really be aimed at SMO. You’d hit the same problem whatever language you use to drive the SMO .NET library. SMO is doing an object/relational mapping for the SQL Server metadata which is never going to be fast. If you really want performance, you can get the best of both worlds by using SMO for the things it is good for, and use SMO’s connection (usually the ExecuteWithResults method but you can do a lot more) to use TSQL to get the more complex information you need. This hybrid approach is dead fast, and as efficient as your TSQL.
Examples? Of course! Here http://www.simple-talk.com/sql/database-administration/powershell-smo-just-writing-things-once/
I’m not meaning to criticise PowerShell or SMO – I find them very useful tools. I find PowerShell extremely handy for getting a wide variety of things done – particularly when T-SQL is just plain clunky (although I think PowerShell can be clunky too, such as in that code for creating Defaults). This post is primarily addressing those people who wonder if PowerShell has access to some secret ability behind the scenes, but I hope doesn’t come across as being negative.
SMO uses deprected stuff all the time as it seem. For example Table.RebuildAllIndexes used DBCC REINDEX
How can we script out a pdw/APS table in powershell?
Sireesh – I’ll have to work that out. PowerShell can’t hook into PDW in the same way.
Hi Rob,
I am looking for PowerShell script to script out the objects from PDW. Could you please help me with this.
Thanks,
Vini