diff --git a/Docs/01_background.md b/Docs/01_background.md new file mode 100644 index 0000000..6d8e430 --- /dev/null +++ b/Docs/01_background.md @@ -0,0 +1,51 @@ +# sp_whoisactive: A Brief History of Activity Monitoring + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Next: [Design Philosophy](02_design.md) +------ + +"Hey DBA! Why is the application so slow?" + +"Hey DBA! Why is my query taking, like, forever to return the results?" + +"Hey DBA! Something is broken! Fix it, quick!" + +If you've been a DBA for 10 minutes or more, you've no doubt heard all of the above statements and every possible transformation of the above statements. A big part of every DBA's job is to understand what's going on when things misbehave. And real-time activity monitoring plays a big part in the quest for insight: if something is broken right now, we need to understand exactly what components are malfunctioning and use that data to quickly make decisions about which course of action to take. **The worst thing a DBA can do is to base a decision on an uninformed guess**. + +In order to avoid guesswork, a monitoring solution must provide plenty of data. Data about the component that's malfunctioning, data about what else is running on the system, and if possible contextual data to help the DBA understand how the system got into the state it's in. That's a lot of data, and over the course of the history of SQL Server the level of availability for this kind of information has ranged from totally unexposed (SQL Server 2000 and earlier) to exposed but difficult to access (SQL Server 2005 and beyond). + +### SQL Server 7.0 and SQL Server 2000: Squinting Through the Fog + +Back in the bad old days of Enterprise Manager, if you wanted to know what was running on your instance you could right-click and select "Current Activity." If Enterprise Manager didn't lock up or take some other completely unpredictable route, the user was rewarded with a list of server processes identifiers, a terse column called "command" that gave a very general indication of what each of those processes was up to, and some basic metrics--CPU, reads, writes, etc--that were known to be woefully inaccurate in most cases. + +More advanced users quickly learned to avoid Enterprise Manager altogether. The same information could be gleaned within Query Analyzer by using the sp_who or sp_who2 procedures, or by querying the sysprocesses view. While using Query Analyzer made data collection faster than it was from the Enterprise Manager user interface, the information was still of the same level of quality--or lack thereof. The screen shot below illustrates the state of the art information shown by these tools. **Session 54 seems to be kind of busy**, I guess? I wonder what it’s up to? Well, since I have no clue and the server is slow, **I should probably just kill it.** + +![F1_01_sp_who2](image/F1_01_sp_who2.jpg) + +Users who were geeky enough to read internals books knew how to get just a bit more information about what the offending session was doing—sort of. The DBCC INPUTBUFFER command would return information about the most recent SQL batch that had been submitted to the server on behalf of the request. This is much better than simply seeing that session 54 is doing some kind of select, but it’s also quite limiting. The SQL submitted might have been a non-parameterized ad hoc batch, in which case seeing what was happening was easy. But as more and more developers learned to use stored procedures, DBCC INPUTBUFFER often returned something as simple as “EXEC SomeStoredProcedure” – and if the procedure had been called via RPC, it wasn’t even possible to see the parameters that were passed in. (And, I should add, it’s still not possible now. A lot has changed in 13 years, but not enough.) + +In order to gain more visibility into what was going on on the server, **many DBAs forgot about these commands altogether** and employed another tool that shipped with SQL Server: Profiler. Most of the DBAs I worked with in the late '90s and early '00s kept Profiler open and attached to the various production instances, all day long. Various information would constantly scroll by and, if there was a problem, the stream could be stopped and the DBA could scroll up and down and try to figure out exactly what the situation was. This technique had its plusses and minuses, to be certain: Profiler showed a lot more information—enough to actually figure out the problem in many cases. But it also showed a lot more information—enough to be overwhelming in many cases. And then there was the fact that Profiler could slow down your entire instance of SQL Server. Which was especially problematic when a whole team of DBAs were all working on the same server, and all had Profiler attached and streaming information. + +### SQL Server 2005: Information Overload + +Clearly, the monitoring situation in SQL Server 2000 was pretty bad. And luckily, Microsoft got the memo. SQL Server 2005 shipped with a set of new monitoring objects called Dynamic Management Views (DMVs). These objects returned a huge amount of information that had never been available in the SQL Server 2000 system views. Many situations that had previously been possible to debug only by getting information from Profiler or a server-side trace were suddenly possible to deal with by running a few SQL queries. The only problem was that for a long time, **no one seemed to know exactly how to write the correct queries**. With scores of DMVs, each with scores of columns, things were overwhelming, and busy DBAs simply didn’t have the time to properly adapt. + +Even Microsoft didn’t seem to be able to leverage these powerful new views. The screen shot below is from SQL Server 2008’s Activity Monitor. The 2008 UI is a lot sharper than the SQL Server 2000 Current Activity UI, and more data is returned by Activity Monitor, but the situation is basically the same as it ever was. **Session 54 is still chugging away, doing, well... something.** + +![F1_02_Activity_Monitor](image/F1_02_Activity_Monitor.jpg) + +To be fair, I can now right-click on any of these rows and find out what SQL is being run by this session. But the user experience is still not even close to user-friendly, and Activity Monitor has a large number of bugs and strange behaviors. Why does it auto-refresh every five seconds? What if I was looking at something? And why do I see a million rows for session 54? There was only one request, wasn’t there? + +Even today, in 2011, **many DBAs I talk to are still using sp_who and sp_who2**. A lot of them are still relying on streaming information from SQL Server Profiler. And while people have finally learned to leverage the DMVs, they often use small, standalone ad hoc scripts and query one or two DMVs to find a very specific bit of information. We’ve progressed from a situation where there is not enough information, to a situation where there are too many places to go for the information that really matters. A lateral move at best. + +### A Personal Journey + +In 2007 I decided to get serious about the DMVs, and I began working on a script to help with monitoring. The first version was posted to my blog on December 31, 2007. + +Now, years later, I have taken that script through countless iterations and I’ve learned a tremendous amount about the various DMVs along the way. The [Who is Active](https://github.com/amachanic/sp_whoisactive/releases) stored procedure correlates a large amount of data from 15 of the DMVs, to allow DBAs to get a complete picture when doing real-time activity monitoring. Although my stored procedure has been well-received and is designed to make it easy to get information from the DMVs, it has a large number of options and a few quirks. So it's no surprise that **I have received numerous requests for in-depth documentation**. That’s the point of this blog series: Over the course of the month I will take you through every corner of Who is Active. I will explain how I use it to do troubleshooting on a daily basis, and I'll give you some insight into how it works and why. + +------ +Next: [Design Philosophy](02_design.md) +------ diff --git a/Docs/02_design.md b/Docs/02_design.md new file mode 100644 index 0000000..adaf631 --- /dev/null +++ b/Docs/02_design.md @@ -0,0 +1,63 @@ +# sp_whoisactive: Design Philosophy + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [A Brief History of Activity Monitoring](01_background.md) Next: [The License](03_license.md) +------ + +As mentioned in [the background article](01_background.md), I have been working on Who is Active for several years. At first it was a standalone script that I would run in an ad hoc manner when I needed some information, but after a short time it became clear that it made a lot of sense to package it up as a stored procedure. + +As time progressed I began adding more and more features on top of the basic functionality, and not surprisingly, the code quickly became extremely complex. In the interest of performance and flexibility I was forced to take what was once a single SQL statement and convert it to utilize dynamic SQL, temporary tables, cursors, error handling, XML, and various other features. Throughout the entire process I’ve attempted to adhere, whenever possible, to a set of basic design principles. These are covered below. + +### Show Only Interesting (Relevant) Data + +The sp_who* family of stored procedures. Enterprise Manager’s Current Activity screen. Activity Monitor. These tools all have one thing in common that makes them much less useful than they could have been: They show every session that’s connected to the SQL Server instance—whether or not any work is being done. On smaller SQL Server instances this doesn’t matter; you get used to ignoring the various system processes, and figure out where to focus to get the pay dirt—information on what your users are actually up to. But some bigger instances, especially those that back numerous application servers using connection pooling, can have hundreds or thousands of connected, sleeping sessions. + +Generally speaking, **when you’re doing activity monitoring, seeing sleeping sessions is a waste of time**. You need to see what’s actively happening on the server, not who has connected and left a session open anytime in recent days. So from the very first versions of Who is Active I simply filtered out anything that was sleeping, with one exception: Sleeping sessions may be holding an open transaction, in which case they may have resources locked. + +Who is Active is called “Who is Active” because—by default—it only shows you information about sessions that are actually doing something. If you want to see all of the other sessions, it can do that too. But you’ll have to ask. + +### Show Simple and Easily-Digestible Information + +Remember session 54 from the background article? Here’s a reminder, via sp_who2: + +![F1_01_sp_who2](image/F1_01_sp_who2.jpg) + +It’s active (it’s doing something), so we’re interested. We see numerous rows because the granularity of these older tools is per-task, not per-request. We’ll get to tasks in a later post, but in the meantime consider this: **The same exact information has been reported numerous times**. There are not, in fact, numerous sessions using session ID 54, each of which are connected to ADAM03 and each of which are running some kind of SELECT. This is extraneous information that just makes our job of figuring out what’s going on that much more difficult. Even worse, all of those numbers (the CPU and DiskIO columns, in case you’re wondering) are each populated at the task level. If you needed to debug at the task level—and in practice, as an end-user you very, very rarely do—that would be great. But for most of us, a single, aggregated CPU time number works fine, thank you very much. (Assuming, of course, that these CPU numbers are even accurate.) + +Here’s the same session, reported in Who is Active: + +![F2_01_WIA](image/F2_01_WIA.jpg) + +No matter how many tasks this session spins up, Who is Active will still return the exact same number of rows: 1. Part of the actual query, if it’s available, is shown right upfront. You can click on the XML if you want to see the full text. I’ve decided against showing the CPU and disk I/O columns in this screen shot because the values are both 0—it turns out that these numbers are quite often reported inaccurately for parallel requests, so the newer DMVs don’t show them in this case. Therefore, Who is Active doesn’t show them either. + +### Impact the Server as Little as Possible; Return Data as Quickly as Possible + +Looking for the cause of a performance problem shouldn’t exacerbate the problem. And **taking a peek at server activity shouldn’t cause a performance problem**. + +The various Microsoft monitoring procedures mentioned in yesterday’s post follow this rule quite well-they run in virtually zero time and will never impact general server performance. Unfortunately, they also provide you with virtually no useful data with which to debug issues, so you might have been better off never looking to begin with. Profiler is the opposite: it can give you lots of data with which to debug, but can also cause the entire instance to grind to a halt. + +For Who is Active I’ve tried to take the middle path: provide enough data to help debug complex issues, while still working extremely hard to avoid impacting the server. In order to accomplish this I’ve disabled automatic creating of statistics on all of the temp tables, employed dirty reads to avoid having the tool block or wait for a lock to be released, used hints to control memory allocations, and use cursors (not so evil after all!) in conjunction with error handling to process certain data in a more granular fashion. + +The end result is pretty good. On most servers, in most situations, the default options return all of the data in under a second. And in the (hopefully rare) cases where the server is under so much stress that things are taking longer than they should, a couple of options can be disabled to make Who is Active collect less data. Speed is especially important to me. I'm not a patient person. **And when you’re debugging a tough issue, the last thing you should have to do is wait a long time to find out what’s going on**. + +### Show as Much Data as Possible Without Going Overboard + +**Who is Active collects data from 15 DMVs**. Each of these DMVs has many columns. That’s a huge number of potential data points that could be displayed. I’ve pruned down this set and have tried to include only those pieces of information that are actually valuable in the vast majority of cases. I don’t want the default Who is Active output to have so many columns that it’s difficult to read and understand. And I don’t want to have to process so much data that things slow down. For this same reason, a lot of the Who is Active features are not enabled by default. If you need a bit more data, it’s usually just a matter of figuring out which parameter to set. + +### Provide a Flexible and Configurable Experience + +You may want the results ordered by session ID descending. I may want them ordered by the amount of time an active request has been running, ascending. You may want to see different columns than I want to see on the left, or on the right. **We both win**. Thanks to some early feedback from Aaron Bertrand, I realized that **one size does not fit all when it comes to monitoring**, and I worked to make the Who is Active procedure as flexible as it can possibly be. The various output configuration features will be covered in detail in a post this later month. + +### Safety and Security + +Who is Active requires slightly elevated permissions **VIEW SERVER STATE** to do its job. And most of the people who run the stored procedure are system administrators with full access to everything on the system. This would be a non-issue if the procedure contained only a simple SELECT statement or two, but for both performance and display purposes I was forced to make heavy use of dynamic SQL. **I have taken every possible precaution to avoid making the procedure vulnerable to any kind of SQL injection attack**: All inputs are not only validated, but also never directly used. All object names encoded in dynamic SQL are safely quoted using QUOTENAME. And all other variables are parameterized. Later this month I’ll describe security in a bit more detail, along with a discussion on how to properly deploy and secure access to the stored procedure. + +### Version Compatibility + +One of my goals at the moment is to keep Who is Active compatible with all builds of SQL Server 2005 and SQL Server 2008. I haven’t done so well here; version 10.00 included a column that wasn’t available until SQL Server 2005 SP2, and many other versions have had similar issues. I have now built a case-sensitive SQL Server 2005 RTM instance in a virtual machine, and plan to test every Who is Active build in that environment going forward. + +------ +Prior: [A Brief History of Activity Monitoring](01_background.md) Next: [The License](03_license.md) +------ diff --git a/Docs/03_license.md b/Docs/03_license.md new file mode 100644 index 0000000..339d4ae --- /dev/null +++ b/Docs/03_license.md @@ -0,0 +1,13 @@ +# sp_whoisactive: The License + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Design Philosophy](02_design.md) Next: [Installing sp_whoisactive](04_installation.md) +------ + +sp_whoisactive uses GPLv3. [You can find the license here](https://github.com/amachanic/sp_whoisactive/blob/master/LICENSE). + +------ +Prior: [Design Philosophy](02_design.md) Next: [Installing sp_whoisactive](04_installation.md) +------ diff --git a/Docs/04_installation.md b/Docs/04_installation.md new file mode 100644 index 0000000..9d6169f --- /dev/null +++ b/Docs/04_installation.md @@ -0,0 +1,47 @@ +# sp_whoisactive: Installing sp_whoisactive + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [The License](03_license.md) Next: [Less Data is More Data](05_lessdata.md) +------ + +An entire post on installation? Isn’t Who is Active just a stored procedure..? +Well, yes. And yes. It might be as easy as [downloading the .ZIP file](https://github.com/amachanic/sp_whoisactive/archive/master.zip), unzipping it, opening the .SQL file in Management Studio, and hitting F5 or CTRL-E. + +But if you’re like some of the people who’ve e-mailed me over the past few years, you may have some questions... + +### What Permissions Are Required? + +Most of what Who is Active does requires **VIEW SERVER STATE** permission. This is a permission level that allows access to the various instance-global DMVs, including the request, session, and transaction related views. In most cases there is no reason to avoid granting this privilege to a user; the main concern is situations where a user might be able to harvest private information by looking at SQL text, especially when it is non-parameterized. These cases being quite few and far between, I consider this to be a relatively low barrier to entry. + +Beyond **VIEW SERVER STATE**, various other **Who is Active features may require access to specific databases**. The most important of these features are locks collection and blocked object name resolution (both of which will be covered in a subsequent post). When these are used, the stored procedure will attempt to access the database in which the lock or blocking is occurring, in order to resolve the affected object names. If the user calling Who is Active does not have sufficient privileges in the database, Who is Active will collect the error message and report it instead of the object name. + +### Which Database Should I Put it In? + +The stored procedure is named “**sp_WhoIsActive**” for a reason: It’s designed to live in the master database; the “**sp_**” prefix, as you’re probably aware, allows a stored procedure in master to be called from the context of any database on the instance. + +I know that many DBAs like to keep all of the DBA scripts in a special-purpose DBA database. Who is Active will work fine from there. But really, it’s much nicer to keep it in master. **Never underestimate the power of convenience**. + +### Help! It Keeps Throwing the Error: “Incorrect syntax near '.'” + +It’s amazing how many times people have written and asked me about this particular error. Not because it’s obvious what’s going on, but because of what it means: You’ve upgraded to SQL Server 2005 or SQL Server 2008 from SQL Server 2000, and **you haven’t updated the database compatibility level**. This error is thrown when a database in SQL Server 2000 compatibility mode encounters a common table expression. It’s not pretty, and it doesn’t need to happen. + +Stop reading this right now and go run the following query against your production SQL Server 2005 or 2008 instances: + +```sql +SELECT * +FROM sys.databases +WHERE + compatibility_level < 100 +``` + +If any rows are returned, think long and hard about why that database needs to be set so as to make your life more difficult. And then update the compatibility level to something that makes sense in 2020, not 1998. + +### Help! It’s Throwing Some Other Error! + +If Who is Active is throwing some error aside from the one above, and it’s not a permissions-related issue, then it’s probably my fault. **create an issue in [GitHub](https://github.com/amachanic/sp_whoisactive/issues), so that I can start working on the problem.** If there is a problem, I want to fix it. And trust me when I say that I take problems with Who is Active very seriously. Most of the features and bug fixes are the result of users telling me what does and does not work for them. I can’t stress enough how much I enjoy both getting, and acting on, your feedback. + +------ +Prior: [The License](03_license.md) Next: [Less Data is More Data](05_lessdata.md) +------ diff --git a/Docs/05_lessdata.md b/Docs/05_lessdata.md new file mode 100644 index 0000000..3983099 --- /dev/null +++ b/Docs/05_lessdata.md @@ -0,0 +1,57 @@ +# sp_whoisactive: Less Data is More Data + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Installing sp_whoisactive](04_installation.md) Next: [Options](06_options.md) +------ + +#### You’ve downloaded Who is Active for the first time. + +You’ve unzipped it. + +You’ve taken a quick peek through the code to make sure I didn’t send you a rejuvenated version of Slammer. + +**You’ve installed it on a test server** so that you can make sure it won’t take down your production environment. (Always a good idea.) + +And now, the moment of truth arrives. You fire up SSMS and—hands ever-so-slightly shaking, breath held, body quaking with anticipation—you type the following: + +```sql +EXEC sp_WhoIsActive +``` + +Your hand slowly approaches the F5 key. Your heart racing, you slowly depress the plastic square and... + +![F5_01_blank](image/F5_01_blank.jpg) + +#### Nothing at all. Where are the results? Is this thing broken? Um, hello?! + +Unfortunately, this is apparently a common scenario for new Who is Active users. (The empty result set. The rest? Well, who knows.) I have received many e-mails and blog comments from people asking why this large, complex stored procedure they’ve just downloaded doesn’t seem to actually do anything when they run it. + +The answer is simple: **It didn’t show you any information because there was nothing interesting to show you**. Unlike sp_who, sp_who2, and most of their brethren, Who is Active—by default—only shows you the sessions that you’re likely to want to see. If you installed it on a test server, or your laptop, or some other non-production machine, you’re probably not going to see any output in the default mode because there is nothing to show you. There are no active requests, and no one has started a transaction and left it sitting around waiting for Who is Active to drop by and monitor. **The lack of output in this case is a good thing**. It means that you don’t have to waste your time trying to find the meaningful information in a sea of worthless data. [I explained this previously in the article on design philosophy](02_design.md). + +#### Seeing More Data – The Basics + +Sometimes you actually do want to see all of the data that Who is Active hides by default. One such time is when you’ve first installed Who is Active and want to get comfortable with it. No problem; if you’d like it to return one row for every session (and more than one row for some sessions, if they’re using Multiple Active Result Sets), you have to work with three options: + +```sql +EXEC sp_WhoIsActive + @show_sleeping_spids = 2, + @show_system_spids = 1, + @show_own_spid = 1 +``` + +Once you’ve done that, the output will look much closer to what you’re probably used to seeing. + +![F5_02_nonblank](image/F5_02_nonblank.jpg) + +The three options shown above will be covered in detail in a future post, but in brief, here’s what we’ve done: +- Changed the default mode from showing only active requests and/or sessions with open transactions to showing all connected sessions +- Changed the default mode from hiding system sessions (even if they fall into the above category) to showing system sessions +- Changed the default mode from hiding your own session—the one calling Who is Active—to showing it along with the rest of the output + +**Many people are uncomfortable, at first, with how little output they see when they run Who is Active**. My recommendation: Try to let go of the need to see everything that’s connected to your SQL Server instances. There’s simply not enough time in the day to bother with that level of detail. + +------ +Prior: [Installing sp_whoisactive](04_installation.md) Next: [Options](06_options.md) +------ diff --git a/Docs/06_options.md b/Docs/06_options.md new file mode 100644 index 0000000..2aa785e --- /dev/null +++ b/Docs/06_options.md @@ -0,0 +1,158 @@ +# sp_whoisactive: Options + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Less Data is More Data](05_lessdata.md) Next: [Default Columns](07_default.md) +------ + +### What fun would life be without lots of choices? + +Activity monitoring, like life, is much more fun (and effective) when you can pick and choose from a variety of options. And the opposite is true: a lack of options makes for a dull, ineffective, one-trick solution. Case in point? sp_who and sp_who2 had only one parameter each. The super-dull "@loginame [sic]." Yes, those crazy kids at Microsoft left out an "n," but it's not like the parameter was well-named. After all, it wasn't just a filter on a login name; it could also be a SPID, or it could be the word "active," which would make it show all sessions that weren't sleeping (including system sessions). Thanks for the straightforward user experience, Microsoft! + +Unlike its predecessors, Who is Active gives you plenty of options with which to work. The procedure has 24 parameters as of the time of this writing; here they are, with their default values: + +```sql +@filter sysname = '' +@filter_type VARCHAR(10) = 'session' +@not_filter sysname = '' +@not_filter_type VARCHAR(10) = 'session' +@show_own_spid BIT = 0 +@show_system_spids BIT = 0 +@show_sleeping_spids TINYINT = 1 +@get_full_inner_text BIT = 0 +@get_plans TINYINT = 0 +@get_outer_command BIT = 0 +@get_transaction_info BIT = 0 +@get_task_info TINYINT = 1 +@get_locks BIT = 0 +@get_avg_time BIT = 0 +@get_additional_info BIT = 0 +@find_block_leaders BIT = 0 +@delta_interval TINYINT = 0 +@output_column_list VARCHAR(8000) = '[dd%][session_id][sql_text][sql_command][login_name][wait_info][tasks][tran_log%][cpu%][temp%][block%][reads%][writes%][context%][physical%][query_plan][locks][%]' +@sort_order VARCHAR(500) = '[start_time] ASC' +@format_output TINYINT = 1 +@destination_table VARCHAR(4000) = '' +@return_schema BIT = 0 +@schema VARCHAR(MAX) = NULL OUTPUT +@help BIT = 0 +``` + + + +#### Parameter Details + +| Parameter Name | Description | +|-|-| +| @filter sysname = ''
@filter_type VARCHAR(10) = 'session'
@not_filter sysname = ''
@not_filter_type VARCHAR(10) = 'session'
| Filters--Both inclusive and exclusive
Set either filter to '' to disable
Valid filter types are: session, program, database, login, and host
Session is a session ID, and either 0 or '' can be used to indicate "all" sessions
All other filter types support % or _ as wildcards | +| @show_own_spid BIT = 0 | Retrieve data about the calling session? | +| @show_system_spids BIT = 0 | Retrieve data about system sessions? | +| @show_sleeping_spids TINYINT = 1


| Controls how sleeping SPIDs are handled, based on the idea of levels of interest
0 does not pull any sleeping SPIDs
1 pulls only those sleeping SPIDs that also have an open transaction
2 pulls all sleeping SPIDs | +| @get_full_inner_text BIT = 0
| If 1, gets the full stored procedure or running batch, when available
If 0, gets only the actual statement that is currently running in the batch or procedure | +| @get_plans TINYINT = 0

| Get associated query plans for running tasks, if available
If @get_plans = 1, gets the plan based on the request's statement offset
If @get_plans = 2, gets the entire plan based on the request's plan_handle | +| @get_outer_command BIT = 0 | Get the associated outer ad hoc query or stored procedure call, if available | +| @get_transaction_info BIT = 0 | Enables pulling transaction log write info and transaction duration | +| @get_task_info TINYINT = 1



| Get information on active tasks, based on three interest levels
Level 0 does not pull any task-related information
Level 1 is a lightweight mode that pulls the top non-CXPACKET wait, giving preference to blockers
Level 2 pulls all available task-based metrics, including:
number of active tasks, current wait stats, physical I/O, context switches, and blocker information | +| @get_locks BIT = 0 | Gets associated locks for each request, aggregated in an XML format | +| @get_avg_time BIT = 0
| Get average time for past runs of an active query
(based on the combination of plan handle, sql handle, and offset) | +| @get_additional_info BIT = 0







| Get additional non-performance-related information about the session or request
text_size, language, date_format, date_first, quoted_identifier, arithabort, ansi_null_dflt_on,
ansi_defaults, ansi_warnings, ansi_padding, ansi_nulls, concat_null_yields_null,
transaction_isolation_level, lock_timeout, deadlock_priority, row_count, command_type

If a SQL Agent job is running, an subnode called agent_info will be populated with some or all of
the following: job_id, job_name, step_id, step_name, msdb_query_error (in the event of an error)

If @get_task_info is set to 2 and a lock wait is detected, a subnode called block_info will be
populated with some or all of the following: lock_type, database_name, object_id, file_id, hobt_id,
applock_hash, metadata_resource, metadata_class_id, object_name, schema_name | +| @find_block_leaders BIT = 0

| Walk the blocking chain and count the number of
total SPIDs blocked all the way down by a given session
Also enables task_info Level 1, if @get_task_info is set to 0 | +| @delta_interval TINYINT = 0
| Pull deltas on various metrics
Interval in seconds to wait before doing the second data pull | +| @output_column_list VARCHAR(8000) = '[dd%][session_id][sql_text][sql_command][login_name][wait_info][tasks][tran_log%][cpu%][temp%][block%][reads%][writes%][context%][physical%][query_plan][locks][%]'






| List of desired output columns, in desired order
Note that the final output will be the intersection of all enabled features and all
columns in the list. Therefore, only columns associated with enabled features will
actually appear in the output. Likewise, removing columns from this list may effectively
disable features, even if they are turned on

Each element in this list must be one of the valid output column names. Names must be
delimited by square brackets. White space, formatting, and additional characters are
allowed, as long as the list contains exact matches of delimited valid column names. | +| @sort_order VARCHAR(500) = '[start_time] ASC'








| Column(s) by which to sort output, optionally with sort directions.
Valid column choices:
session_id, physical_io, reads, physical_reads, writes, tempdb_allocations,
tempdb_current, CPU, context_switches, used_memory, physical_io_delta, reads_delta,
physical_reads_delta, writes_delta, tempdb_allocations_delta, tempdb_current_delta,
CPU_delta, context_switches_delta, used_memory_delta, tasks, tran_start_time,
open_tran_count, blocking_session_id, blocked_session_count, percent_complete,
host_name, login_name, database_name, start_time, login_time, program_name

Note that column names in the list must be bracket-delimited. Commas and/or white
space are not required. | +| @format_output TINYINT = 1


| Formats some of the output columns in a more "human readable" form
0 disables outfput format
1 formats the output for variable-width fonts
2 formats the output for fixed-width fonts | +| @destination_table VARCHAR(4000) = ''


| If set to a non-blank value, the script will attempt to insert into the specified
destination table. Please note that the script will not verify that the table exists,
or that it has the correct schema, before doing the insert.
Table can be specified in one, two, or three-part format | +| @return_schema BIT = 0
@schema VARCHAR(MAX) = NULL OUTPUT


| If set to 1, no data collection will happen and no result set will be returned; instead,
a CREATE TABLE statement will be returned via the @schema parameter, which will match
the schema of the result set that would be returned by using the same collection of the
rest of the parameters. The CREATE TABLE statement will have a placeholder token of
in place of an actual table name. | + +#### Output Columns Detail + +| formatted_column_name | formatted_column_type | unformatted_column_name | unformatted_column_type | description | +|-|-|-|-|-| +| [session_id] | [smallint] NOT NULL | | | Session ID (a.k.a. SPID) | +| [dd hh:mm:ss.mss]
| [varchar](15) NULL
|
| 0
| For an active request, time the query has been running
For a sleeping session, time since the last batch completed | +| [dd hh:mm:ss.mss (avg)]
| [varchar](15) NULL
| [avg_elapsed_time]
| [int] NULL
| (Requires @get_avg_time option)
How much time has the active portion of the query taken in the past, on average? | +| [physical_io] | [varchar](30) NULL | [physical_io] | [bigint] NULL | Shows the number of physical I/Os, for active requests | +| [reads]
| [varchar](30) NULL
| [reads]
| [bigint] NULL
| For an active request, number of reads done for the current query
For a sleeping session, total number of reads done over the lifetime of the session | +| [physical_reads]
| [varchar](30) NULL
| [physical_reads]
| [bigint] NULL
| For an active request, number of physical reads done for the current query
For a sleeping session, total number of physical reads done over the lifetime of the session | +| [writes]
| [varchar](30) NULL
| [writes]
| [bigint] NULL
| For an active request, number of writes done for the current query
For a sleeping session, total number of writes done over the lifetime of the session | +| [tempdb_allocations]
| [varchar](30) NULL
| [tempdb_allocations]
| [bigint] NULL
| For an active request, number of TempDB writes done for the current query
For a sleeping session, total number of TempDB writes done over the lifetime of the session | +| [tempdb_current]
| [varchar](30) NULL
| [tempdb_current]
| [bigint] NULL
| For an active request, number of TempDB pages currently allocated for the query
For a sleeping session, number of TempDB pages currently allocated for the session | +| [CPU]
| [varchar](30) NULL
| [CPU]
| [int] NULL
| For an active request, total CPU time consumed by the current query
For a sleeping session, total CPU time consumed over the lifetime of the session | +| [context_switches] | [varchar](30) NULL | [context_switches] | [bigint] NULL | Shows the number of context switches, for active requests | +| [used_memory]
| [varchar](30) NOT NULL
| [used_memory]
| [bigint] NOT NULL
| For an active request, total memory consumption for the current query
For a sleeping session, total current memory consumption | +| [physical_io_delta]

| [varchar](30) NULL

| [physical_io_delta]

| [bigint] NULL

| (Requires @delta_interval option)
Difference between the number of physical I/Os reported on the first and second collections.
If the request started after the first collection, the value will be NULL | +| [reads_delta]

| [varchar](30) NULL

| [reads_delta]

| [bigint] NULL

| (Requires @delta_interval option)
Difference between the number of reads reported on the first and second collections.
If the request started after the first collection, the value will be NULL | +| [physical_reads_delta]

| [varchar](30) NULL

| [physical_reads_delta]

| [bigint] NULL

| (Requires @delta_interval option)
Difference between the number of physical reads reported on the first and second collections.
If the request started after the first collection, the value will be NULL | +| [writes_delta]

| [varchar](30) NULL

| [writes_delta]

| [bigint] NULL

| (Requires @delta_interval option)
Difference between the number of writes reported on the first and second collections.
If the request started after the first collection, the value will be NULL | +| [tempdb_allocations_delta]

| [varchar](30) NULL

| [tempdb_allocations_delta]

| [bigint] NULL

| (Requires @delta_interval option)
Difference between the number of TempDB writes reported on the first and second collections.
If the request started after the first collection, the value will be NULL | +| [tempdb_current_delta]

| [varchar](30) NULL

| [tempdb_current_delta]

| [bigint] NULL

| (Requires @delta_interval option)
Difference between the number of allocated TempDB pages reported on the first and second
collections. If the request started after the first collection, the value will be NULL | +| [CPU_delta]

| [varchar](30) NULL

| [CPU_delta]

| [int] NULL

| (Requires @delta_interval option)
Difference between the CPU time reported on the first and second collections.
If the request started after the first collection, the value will be NULL | +| [context_switches_delta]

| [varchar](30) NULL

| [context_switches_delta]

| [bigint] NULL

| (Requires @delta_interval option)
Difference between the context switches count reported on the first and second collections
If the request started after the first collection, the value will be NULL | +| [used_memory_delta]
| [varchar](30) NULL
| [used_memory_delta]
| [bigint] NULL
| Difference between the memory usage reported on the first and second collections
If the request started after the first collection, the value will be NULL | +| [tasks] | [varchar](30) NULL | [tasks] | [smallint] NULL | Number of worker tasks currently allocated, for active requests | +| [status] | [varchar](30) NOT NULL | 0 | 0 | Activity status for the session (running, sleeping, etc) | +| [wait_info]







| [nvarchar](4000) NULL







| 0







| 0







| Aggregates wait information, in the following format:
(Ax: Bms/Cms/Dms)E
A is the number of waiting tasks currently waiting on resource type E. B/C/D are wait
times, in milliseconds. If only one thread is waiting, its wait time will be shown as B.
If two tasks are waiting, each of their wait times will be shown (B/C). If three or more
tasks are waiting, the minimum, average, and maximum wait times will be shown (B/C/D).
If wait type E is a page latch wait and the page is of a "special" type (e.g. PFS, GAM, SGAM),
the page type will be identified.
If wait type E is CXPACKET, the nodeId from the query plan will be identified | +| [locks]


| [xml] NULL


| 0


| 0


| (Requires @get_locks option)
Aggregates lock information, in XML format.
The lock XML includes the lock mode, locked object, and aggregates the number of requests.
Attempts are made to identify locked objects by name | +| [tran_start_time]

| [datetime] NULL

| 0

| 0

| (Requires @get_transaction_info option)
Date and time that the first transaction opened by a session caused a transaction log
write to occur. | +| [tran_log_writes]




| [nvarchar](4000) NULL




| 0




| 0




| (Requires @get_transaction_info option)
Aggregates transaction log write information, in the following format:
A:wB (C kB)
A is a database that has been touched by an active transaction
B is the number of log writes that have been made in the database as a result of the transaction
C is the number of log kilobytes consumed by the log records | +| [open_tran_count] | [varchar](30) NULL | [open_tran_count] | [smallint] NULL | Shows the number of open transactions the session has open | +| [sql_command]

| [xml] NULL

| [sql_command]

| [nvarchar]

| (Requires @get_outer_command option)
Shows the "outer" SQL command, i.e. the text of the batch or RPC sent to the server,
if available | +| [sql_text]






| [xml] NULL






| [sql_text]






| [nvarchar]






| Shows the SQL text for active requests or the last statement executed
for sleeping sessions, if available in either case.
If @get_full_inner_text option is set, shows the full text of the batch.
Otherwise, shows only the active statement within the batch.
If the query text is locked, a special timeout message will be sent, in the following format:

If an error occurs, an error message will be sent, in the following format:
| +| [query_plan]




| [xml] NULL




| 0




| 0




| (Requires @get_plans option)
Shows the query plan for the request, if available.
If the plan is locked, a special timeout message will be sent, in the following format:

If an error occurs, an error message will be sent, in the following format:
| +| [blocking_session_id] | [smallint] NULL | 0 | 0 | When applicable, shows the blocking SPID | +| [blocked_session_count]

| [varchar](30) NULL

| [blocked_session_count]

| [smallint] NULL

| (Requires @find_block_leaders option)
The total number of SPIDs blocked by this session,
all the way down the blocking chain. | +| [percent_complete] | [varchar](30) NULL | [percent_complete] | [real] NULL | When applicable, shows the percent complete (e.g. for backups, restores, and some rollbacks) | +| [host_name] | [sysname] NOT NULL | 0 | 0 | Shows the host name for the connection | +| [login_name] | [sysname] NOT NULL | 0 | 0 | Shows the login name for the connection | +| [database_name] | [sysname] NULL | 0 | 0 | Shows the connected database | +| [program_name] | [sysname] NULL | 0 | 0 | Shows the reported program/application name | +| [additional_info]


| [xml] NULL


| 0


| 0


| (Requires @get_additional_info option)
Returns additional non-performance-related session/request information
If the script finds a SQL Agent job running, the name of the job and job step will be reported
If @get_task_info = 2 and the script finds a lock wait, the locked object will be reported | +| [start_time]
| [datetime] NOT NULL
| 0
| 0
| For active requests, shows the time the request started
For sleeping sessions, shows the time the last batch completed | +| [login_time] | [datetime] NOT NULL | 0 | 0 | Shows the time that the session connected | +| [request_id]
| [int] NULL
| 0
| 0
| For active requests, shows the request_id
Should be 0 unless MARS is being used | +| [collection_time] | [datetime] NOT NULL | | | Time that this script's final SELECT ran | + +I could write a few sentences about each option, but I've already done that. You can find short descriptions in the comment header I've included with Who is Active. But I don't want you to have to print that out, and neither should you be expected to memorize 24 parameters (at least, not right away). Instead of doing either of those things, **focus your attention on the most important parameter of all: the last one**. + +@help, when set to 1, causes the procedure to return the same text found in the comment header, nicely formatted (well, sort of) in the SSMS results pane. Like this: + +![F6_01_help](image/F6_01_help.jpg) + +There are two results in the output: the first contains information about all of the available input parameters; the second contains information about all of the output columns. + +Once you understand the options fairly well, you can use the help in another way, to set up your own custom script to call Who is Active. Select the first column (click the header that says “parameter”), and use CTRL-C and CTRL-V to copy and paste the text into a new window. Add a call to Who is Active, remove a few lines, pop in a few commas, and you’ll have something like this: + +```sql +EXEC sp_WhoIsActive + @filter = '', + @filter_type = 'session', + @not_filter = '', + @not_filter_type = 'session', + @show_own_spid = 0, + @show_system_spids = 0, + @show_sleeping_spids = 1, + @get_full_inner_text = 0, + @get_plans = 0, + @get_outer_command = 0, + @get_transaction_info = 0, + @get_task_info = 1, + @get_locks = 0, + @get_avg_time = 0, + @get_additional_info = 0, + @find_block_leaders = 0, + @delta_interval = 0, + @output_column_list = '[dd%][session_id][sql_text][sql_command][login_name][wait_info][tasks][tran_log%][cpu%][temp%][block%][reads%][writes%][context%][physical%][query_plan][locks][%]', + @sort_order = '[start_time] ASC', + @format_output = 1, + @destination_table = '', + @return_schema = 0, + @schema = NULL, + @help = 0 +``` + +Save this to a script, and you’ll be able to easily and quickly call the procedure using any of the parameter combinations you like, without having to type them all in every time. **It’s almost like intellisense that actually works!** + +------ +Prior: [Less Data is More Data](05_lessdata.md) Next: [Default Columns](07_default.md) +------ diff --git a/Docs/07_default.md b/Docs/07_default.md new file mode 100644 index 0000000..c9f9c1d --- /dev/null +++ b/Docs/07_default.md @@ -0,0 +1,67 @@ +# sp_whoisactive: Default Columns + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Options](06_options.md) Next: [Active Request, Sleeping Session](08_requests.md) +------ + +### Part of the battle of writing Who is Active is achieving the proper level of balance between enough information and too much information. + +It’s important to return sufficient data to help debug the most common problems without users having to tweak the parameters. And it’s important to restrict the amount of data sent back so that the default output is not overwhelming, nor is the performance of the procedure sacrificed. + +Following are the current default columns, broken into four basic categories: + +#### Time and Status +```sql +[dd hh:mm:ss.mss] +[start_time] +[percent_complete] +[collection_time] +[status] +``` + +#### Identifiers +```sql +[session_id] +[request_id] +[login_name] +[host_name] +[database_name] +[program_name] +``` + +#### Things Slowing Down Your Query +```sql +[wait_info] +[blocking_session_id] +``` + +#### Things Your Session is Doing +```sql +[sql_text] +[CPU] +[tempdb_allocations] +[tempdb_current] +[reads] +[writes] +[physical_reads] +[used_memory] +[open_tran_count] +``` + +Each set of columns deserves some description, and we’ll start with **Time and Status**. These columns tell you how long your query has been running ([start_time] and its cousin, the “convenience column” [dd hh:mm:ss.mss]), how much longer things might be running ([percent_complete]), whether anything is running at all ([status]), and a record of when you asked ([collection_time]). + +The **Identifiers** are ways of telling one session—or class of sessions—apart from another. The [session_id] and [request_id] columns are, of course, SQL Server’s way of doing this, while the rest of the columns are more human-readable. Note that [request_id] will almost always have a value of 0 for active requests (those where the [status] column has any value other than “sleeping”), and NULL for sleeping sessions. This is not quite the same as the way the data is represented in the sysprocesses DMV, but I don’t think it makes sense to have any [request_id] when there is no request. To see a value greater than 0, you’ll have to use MARS in your application. Not a common thing, which is why this column shows up on the far righthand side of the output. + +The **Things Slowing Down Your Query** columns describe wait states and information about blocking. I’ll get into these in detail in a later post. + +Finally, the **Things Your Session is Doing** columns give information about what is happening, or has happened, on behalf of your session. At this point in the series it’s worth sharing further information about a few of the less obvious of these columns: + +- **The most confusing of these columns are those related to tempdb**. Each of the columns reports a number of 8 KB pages. The [tempdb_allocations] column is collected directly from the tempdb-related DMVs, and indicates how many pages were allocated in tempdb due to temporary tables, LOB types, spools, or other consumers. The [tempdb_current] column is computed by subtracting the deallocated pages information reported by the tempdb DMVs from the number of allocations. Seeing a high number of allocations with a small amount of current pages means that your query may be slamming tempdb, but is not causing it to grow. Seeing a large number of current pages means that your query may be responsible for all of those auto-grows you keep noticing. +- The [used_memory] column is also reported based on a number of 8 KB pages. The number a combination of both procedure cache memory and workspace memory grant. +- **[open_tran_count] is by far the most useful column that Who is Active pulls from the deprecated sysprocesses view**. And only from that view, since Microsoft has not bothered replicating it elsewhere. It can be used not only to tell whether the session has an active transaction, but also to find out how deeply nested the transaction is. This is invaluable information when debugging situations where applications open several nested transactions and don’t send enough commits to seal the deal. + +------ +Prior: [Options](06_options.md) Next: [Active Request, Sleeping Session](08_requests.md) +------ diff --git a/Docs/08_requests.md b/Docs/08_requests.md new file mode 100644 index 0000000..32e1dfe --- /dev/null +++ b/Docs/08_requests.md @@ -0,0 +1,56 @@ +# sp_whoisactive: Active Request, Sleeping Session + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Default Columns](07_default.md) Next: [Deciding What \(Not\) To See](09_deciding.md) +------ + +### The life cycle of a connection can be represented by a few simple phases: + +- Connect +- Query +- Sleep +- (Repeat query and sleep as needed) +- Disconnect + +Who is Active, being a real-time activity monitoring tool, is designed to help track activity in those middle phases. The procedure doesn’t capture statistics about connections, and similarly it can’t report (very well) on anything that has already disconnected. + +Most of the time—assuming that your workload is relatively normal—**the majority of the sessions that you'll see reported by Who is Active will be in the Query phase**. But due to open transactions, queries in the Sleep phase may also sneak in. And in some extreme cases, you might even see a query in the Disconnect phase. More on that in a bit. + +So why does this matter? It all boils down to a simple question: How should session-level data be represented? The legacy sysprocesses view more or less mashed everything together. The execution context DMVs, on the other hand, split things up so that data from the Query phase is found in a request-level view, and aggregate data updated as soon as the Sleep phase begins, in a session-level view. My choices were, therefore, as follows: + +- Mash everything together, like sysprocesses +- Treat sleeping sessions and active requests differently +- Create two columns for each metric: one for session-level data and another for request-level data + +The first option was out before I even thought through the possibilities. As I mentioned [in the first post in this series](01_background.md), I find the quality of data reported by sysprocesses to be, well, lacking. + +The third option seemed interesting, but one of my goals with Who is Active was to keep things [simple and easily digestible](02_design.md). Having a million columns kind of defeats that purpose. + +So in the end, my only choice was the middle path: the **data from sleeping sessions and active requests is both reported by Who is Active, but never at the same time for the same session**. This is one of those things that’s best represented by an image: + +![F7_01_active_sleeping](image/F7_01_active_sleeping.jpg) + +**The most important thing to look at in this example is the [status] column**—so I’ve dragged it all the way over. If the status is “sleeping,” it means that all of the values reported by Who is Active for that session are session-level metrics. If the status is anything other than “sleeping” (most commonly “running,” “runnable,” or “suspended”), then the values reported are all request-level metrics. + +In this case, starting from the left: + +- [dd hh:mm:ss.mss] for a sleeping session refers to the amount of time elapsed since login time. For a request it’s the amount of time the entire batch—not just the current statement—has been running. +- [sql_text] for a sleeping session is the last batch run on behalf of the session. For a request it’s the currently-running statement (at least, by default). +- [wait_info] is always NULL for a sleeping session. +- [CPU] and [reads] are session-level metrics (aggregates across all requests processed since login) for sleeping sessions, and request-level metrics (relevant only as far as the current request) for active requests. + +The same can be said for virtually every metric reported by Who is Active. When in doubt, check out the [status] column. If you find that Who is Active is returning a lot of sleeping sessions due to your workload, you might want to move the [status] column a bit to the left in the default output, so that it’s easier to quickly check. I don’t usually find that to be necessary, so it’s toward the middle in the current default settings. + +There is one other state that a session can be in and still get reported by Who is Active: an almost-completed state. Who is Active collects data in two phases, and in newer builds I decided that if some activity is caught on the first pass, it should be reported even if the session has disconnected, or a new and different request started, by the second pass. The second phase generally begins only a few milliseconds after the first, but on active OLTP systems it’s common for most requests to not even take that long. The goal is to report as much data as possible. These almost-completed (or almost-disconnected) sessions look like this: + +![F7_02_disconnected](image/F7_02_disconnected.jpg) + +The status is “suspended,” because that’s what it was in the first collection phase—so it looks like a normal active request. The giveaway that something changed by the second phase? CPU, reads, and writes are all NULL. That means that a suitable matching row didn’t exist in either sys.dm_exec_requests or sys.dm_exec_sessions by the time the second phase kicked in—so the session must have either disconnected or started a new request. When this happens the [dd hh:mm:ss.mss] column reports the time elapsed since the session originally logged in. It’s the only interesting time metric I can get when this occurs. + +As a final note: if you see a lot of sleeping sessions showing up in the default Who is Active view, you might want to ask some questions of your application developer colleagues. Why is the application beginning transactions and letting them sit around for long periods of time? This is generally not a great I idea, for a number of reasons that I hope are rather obvious to anyone reading this post. + +------ +Prior: [Default Columns](07_default.md) Next: [Deciding What \(Not\) To See](09_deciding.md) +------ diff --git a/Docs/09_deciding.md b/Docs/09_deciding.md new file mode 100644 index 0000000..6f07216 --- /dev/null +++ b/Docs/09_deciding.md @@ -0,0 +1,87 @@ +# sp_whoisactive: Deciding What (Not) To See + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Active Request, Sleeping Session](08_requests.md) Next: [Commands, Batches, and the Mysteries of Text](10_commands.md) +------ + +I previously explained that in the world of monitoring, [Less Data is More Data](05_lessdata.md). + +The goal, again, is to avoid being distracted by a bunch of information that doesn’t matter. Your job is to find and fix the real issues, as quickly as possible. + +It’s only natural that during the finding phase you might wish to focus in on some particular class of user, or application, or whatever. And that means **filters**. + +By default, Who is Active filters out any session that’s not active or that doesn’t have an active request. It also filters out information about the session running Who is Active—i.e., you. The idea is that you’re probably not interested in what Who is Active is up to unless you either have way too much time on your hands, your name is Adam Machanic, or both. + +If you would like to change any of the default filtered behavior, you can do so using a few options that I introduced in the Less Data is More Data post: + +- **@show_sleeping_spids** defaults to a value of **1**, which means that the only sleeping sessions that will be shown are those that have an open transaction. If you would like to see all sleeping sessions, set the parameter to a value of **2**. And if you wouldn’t like to see any, regardless of whether there is an open transaction, set it to **0**. +- **@show_system_spids** can be set to **1** to capture information about background and system processes. It’s generally not very interesting to look at these, with the exception of seeing activity being done by Service Broker activation procedures—and those sessions are already shown by default in newer versions of by Who is Active. +- **@show_own_spid** can be set to **1** to capture information about the session you’re running Who is Active from. You’ll see a small chunk of the code that’s running, and it won’t be very insightful, but I’ve included the option for completeness. + +Beyond the default filters, Who is Active supports the ability to do text filtering on various columns. To see how Who is Active deals with these text filters, let’s take a look at a sample set that might be returned by Who is Active: + +![F8_lots_of_activity](image/F8_lots_of_activity.jpg) + +This blat guy sure is running a lot of queries! I’m much more interested in what Adam is up to (go figure). To reduce the set to see only Adam’s activity, I can employ a filter: + +```sql +EXEC sp_WhoIsActive + @filter_type = 'login', + @filter = 'Adam03\Adam' +``` + +![F8_just_adam](image/F8_just_adam.jpg) + +This filter gives me an exact match on “Adam03\Adam” in the [login_name] column. And that’s great, but a lot more can be done. + +#### Who is Active supports five filter types: + +- “session” filters on the [session_id] column +- “program” filters on the [program_name] column +- “database” filters on the [database_name] column +- “login” filters on the [login_name] column +- “host” filters on the [host_name] column + +Session is special because of the five filter types it is the only one that is numeric. “Filtering” using the “session” filter on a value of “0” returns all of the sessions to be shown based on whatever other filter options you’re working with. A non-zero value will return information only about the session you’ve specified—again, subject to other filter options. This means that if you’re looking for information on session_id 96, but that session is sleeping, and you have @show_sleeping_spids set to 0, you’re not going to see any information. **Always remember that the filters are additive**. + +The other four filter types are quite a bit more flexible, because they are pure text filters. And **text filters support wildcards**. The same kinds of wildcards that you can use for LIKE or PATINDEX. Meaning that you can write the above query in a number of ways, depending on how flexible you would like to be with which sessions are returned: + +```SQL +EXEC sp_WhoIsActive + @filter_type = 'login', + @filter = 'A%'; + +EXEC sp_WhoIsActive + @filter_type = 'login', + @filter = '%dam'; + +EXEC sp_WhoIsActive + @filter_type = 'login', + @filter = 'A[de]am03\[^B]dam'; +``` + +**Another option is to ask Who is Active to not show certain sessions**. This is referred to as a “not-filter,” and works the same way. If you want to see everything except what blat is up to, you can do: + +```sql +EXEC sp_WhoIsActive + @not_filter_type = 'login', + @not_filter = 'blat'; +``` + +The not-filter option was added after some great feedback from Michelle Ufford, who was trying to use Who is Active on a system that was always busy running a huge number of automated jobs and processes. Since all of these had been running for quite some time and were rather uninteresting, Michelle wanted to see only the other, non-automated activity on the system. Not-filters support the same filter types as normal text filters, and also support wildcards. And of course, both filter types can be combined: + +```sql +EXEC sp_WhoIsActive + @filter_type = 'login', + @filter = 'A%', + @not_filter_type = 'login', + @not_filter = 'b%'; +``` + +The current set of Who is Active filters are, in my opinion, quite flexible, but I don’t feel completely satisfied. My goal is to eventually convert the entire filter mechanism to an expression language that supports arbitrarily complex filters. This would, of course, also [have to be 100% injection safe, and perform extremely well](02_design.md), so it’s a bit of a dream at the moment. But it’s an interesting problem, so I’ll continue to work on it and perhaps I’ll crack it in a future version of Who is Active. + +------ +Prior: [Active Request, Sleeping Session](08_requests.md) Next: [Commands, Batches, and the Mysteries of Text](10_commands.md) +------ diff --git a/Docs/10_commands.md b/Docs/10_commands.md new file mode 100644 index 0000000..129dd2f --- /dev/null +++ b/Docs/10_commands.md @@ -0,0 +1,161 @@ +# sp_whoisactive: Commands, Batches, and the Mysteries of Text + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Deciding What \(Not\) To See](09_deciding.md) Next: [Planning for Success](11_planning.md) +------ + +Remember the saga of SPID 54? In case you’ve forgotten its sad tale, let’s revisit: + +![F1_02_Activity_Monitor](image/F1_02_Activity_Monitor.jpg) + +There it is. 54. **Doing something, as usual. And of course, that something is not exactly apparent** from the above sp_who2 output. + +This is such a major defect that when I wrote Who is Active I decided to show query text by default even if it slightly slowed things down in some cases. This can be disabled—we’ll get to that in a later post—but I don’t think anyone does that very often. + +To understand the differences between the options, consider the following batch: + +```sql +SELECT * +FROM sys.tables + +WAITFOR DELAY '10:10:10' + +SELECT * +FROM sys.databases +GO +``` + +Running this batch on session 53, then running sp_WhoIsActive on another session, the following is output: + +![F10_01_default](image/F10_01_default.jpg) + +The [sql_text] column, by default, outputs the text of the statement that is currently running. We can instead decide to see the entire batch, by setting @get_full_inner_text: + +```sql +EXEC sp_WhoIsActive + @get_full_inner_text = 1 +``` + +![F10_01_full_text](image/F10_01_full_text.jpg) + +**Why is this option called “get full inner text” rather than “get full batch?”** It’s assumed that in most systems (hopefully) the majority of code running will be stored procedure calls rather than ad hoc batches. Let’s see what happens in that case: + +```sql +USE tempdb +GO + +CREATE PROC test_proc +AS +BEGIN + SELECT * + FROM sys.tables + + WAITFOR DELAY '10:10:10' + + SELECT * + FROM sys.databases +END +GO + +EXEC test_proc +GO +``` + +Running Who is Active with the default mode outputs pretty much the same exact thing as before: + +![F10_03_default](image/F10_03_default.jpg) + +Setting the @get_full_inner_text option now returns the entire text of the stored procedure—or the “full inner text.” + +![F10_03_full_text](image/F10_03_full_text.jpg) + +**If you’re wondering what ” +- Certain system features, such as automatic statistics updates, may cause surprising results to be returned in the [sql_text] column. For example, rebuilding an index will result in text along the lines of “insert [dbo].[yourTable] select * from [dbo].[yourTable].” If you see something like this, do not be alarmed! Take a deep breath and use the @get_outer_command option to find out what’s really going on. + +------ +Prior: [Deciding What \(Not\) To See](09_deciding.md) Next: [Planning for Success](11_planning.md) +------ diff --git a/Docs/11_planning.md b/Docs/11_planning.md new file mode 100644 index 0000000..80484e5 --- /dev/null +++ b/Docs/11_planning.md @@ -0,0 +1,64 @@ +# sp_whoisactive: "Planning" for Success + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Commands, Batches, and the Mysteries of Text](10_commands.md) Next: [The Almighty Transaction](12_transaction.md) +------ + +**[Viewing the text of the currently running statement](11_planning.md) is a big part of the debugging battle**. Another part is being able to quickly see the associated query plan. + +Due to performance concerns Who is Active does not show the query plan by default; plans for big queries can sometimes span several megabytes of XML, so accessing the plan can be expensive. **Enabling plan retrieval is simple: Use the @get_plans option**. + +@get_plans has two modes: + +- Setting the option to **1** will get the plan for the currently running statement +- Setting the option to **2** will get the entire plan for all queries in the currently running batch + +These settings align, more or less, with the default statement text retrieval mode and the @get_full_inner_text option. + +Consider the following batch: + +```sql +SELECT + * +FROM sys.databases + +WAITFOR DELAY '10:10:10' + +SELECT + * +FROM sys.tables +GO +``` + +Running this, then running Who is Active with @get_plans set to 1, results in the addition of the [query_plan] column to the output: + +![F11_01_xml_plan](image/F11_01_xml_plan.jpg) + +The query plan is an XML showplan, and the next step for seeing the graphical version of the plan is to click on the XML instance. This will bring up a new tab in Management Studio, but **what happens next depends on which version of SSMS you’re running**. If you’re still using the SQL Server 2005 version, you’ll be greeted with a screen full of XML: + +![F11_02_xml](image/F11_02_xml.jpg) + +To see the plan rendered in a nice graphical format, save the XML to a file with the .SQLPLAN extension, close the file in Management Studio, then re-open it. Or, if you’re using the SQL Server 2008 version of Management Studio, forget all of the XML file stuff and just click. Either way you’ll be greeted with: + +![F11_02_graphic](image/F11_02_graphic.jpg) + +The other option is to see the plan for the entire batch. Or, phrased another way, all of the plans for each of the statements in the batch. It’s as easy as... + +```sql +EXEC sp_WhoIsActive + @get_plans = 2 +``` + +![F11_02_full](image/F11_02_full.jpg) + +#### Notes + +- Plan collection, like statement text collection, may time out due to a lock. (See the Homework section below.) +- Both the plan and the statement text may be unavailable due to the presence of “non query” statements in the batch. Various statement types apply, and it’s not documented, but the most common problem I see is when a stored procedure uses ALTER TABLE to add a primary key to a temporary table. This disables caching for the entire stored procedure, making it impossible for Who is Active to retrieve either the text or the plan. +- **A few people have asked whether the plans returned by Who is Active are the “actual” or “estimated” plans**. The answer depends on how you define these terms. "Actual plan" usually refers to the query plan that has the actual row counts, number of executions for each iterator, and various other information that can only be collected once a query has completed. Who is Active cannot return that version of the plan. But the plan it returns is indeed the "actual" plan that's running at the time; in other words, the plan will not be recompiled into some other plan by the time Who is Active can get it. + +------ +Prior: [Commands, Batches, and the Mysteries of Text](10_commands.md) Next: [The Almighty Transaction](12_transaction.md) +------ diff --git a/Docs/12_transaction.md b/Docs/12_transaction.md new file mode 100644 index 0000000..a3f2382 --- /dev/null +++ b/Docs/12_transaction.md @@ -0,0 +1,113 @@ +# sp_whoisactive: The Almighty Transaction + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Planning for Success](11_planning.md) Next: [How Queries Are Processed](13_queries.md) +------ + +**Virtually everything that SQL Server does is tied to a transaction**. Therefore, it is of utmost importance when monitoring to be able to find out what’s going on with the various transactions that are active on your SQL Server instances. + +In its default mode Who is Active shows any session with an active transaction. This state is reflected in the [open_tran_count] column, the value of which is the depth of nested transactions that have been started—implicitly or explicitly—on the request or session. + +```sql + --SPID 53 + BEGIN TRAN + BEGIN TRAN + BEGIN TRAN + BEGIN TRAN + GO +``` + +![F12_01_open_tran_count](image/F12_01_open_tran_count.jpg) + +Here the [open_tran_count] is 4, because there are four nested transactions. These transactions could have been created at various levels of scope—e.g. inside of nested stored procedures—and it is not uncommon to see cases where not enough commits are issued to match the numbered of transactions that have been started. + +There are a number of transaction-related DMVs, all of which are named using the *sys.dm_tran* prefix. Who is Active currently uses three of these to expose additional information beyond the open transaction count. **To see more information, enable the @get_transaction_info option**. This option adds two columns to the Who is Active output: + +- The [tran_log_writes] column includes information about any database that has been written to +on behalf of the transaction. The format for this data is a comma-delimited list, in the following form per database: + - {database name} {number of log records written} ({size of log records} kB) + +- **The [tran_start_time] column reflects the time that the first database was written to** on behalf of the transaction. This is perhaps a bit counter-intuitive, but the idea is simple: for the most part it’s not interesting to see a lot of information about read-only transactions. Millions of them start and finish every day on the average SQL Server instance. Transactions that are actually doing some work—writing something—are the ones that tend to cause the issues. Therefore, Who is Active focuses its energy there. + +To see these two columns in action, leave session 53 active, and create a couple of test databases to play with: + +```sql +USE master +GO + +CREATE DATABASE test_db1 +GO + +CREATE DATABASE test_db2 +GO + +CREATE TABLE test_db1.dbo.t1 +( + i INT +) +GO + +CREATE TABLE test_db2.dbo.t2 +( + i INT +) +GO +``` + +Once these are created, we can insert some rows into one of the tables inside of a multi-statement transaction... + +```sql +BEGIN TRAN +GO + +INSERT test_db1.dbo.t1 +( + i +) +SELECT + number +FROM master..spt_values +WHERE + type = 'p' +GO +``` + +The INSERT results in 2048 rows inserted into *test_db1.dbo.t1*. And since we haven’t committed the transaction yet, it’s still alive for Who is Active to catch. + +```sql +EXEC sp_WhoIsActive + @get_transaction_info = 1 +``` + +![F12_02_start_time](image/F12_02_start_time.jpg) + +Session 52—the one on which I’ve just inserted the rows, has information in both the [tran_log_writes] and [tran_start_time] columns. Session 53, on the other hand, has NULLs for both columns—even though it’s still holding an open transaction. The reason is that session 52 has actually done a write in *test_db1*, whereas session 53 has not done any work at all. + +So far only one database has been touched in the transaction. Adding another database to the mix adds that database to the [tran_log_writes] output: + +```sql +INSERT test_db2.dbo.t2 +( + i +) +SELECT + number +FROM master..spt_values +WHERE + type = 'p' +GO +``` + +![F12_02_two_dbs](image/F12_02_two_dbs.jpg) + +The same amount of work has been done in both databases: 2048 rows inserted into a table. And we can see that this has produced the same number of transaction log records, and the same amount of transaction log space is being consumed in the log files of each database. That makes a lot of sense. It also makes sense that we’re seeing 2049 log records, because that corresponds to one log header record and one log record for each of the 2048 affected rows. + +**Taking this a bit further makes things much very interesting for those of you doing ETL**: consider that in any situation in which minimal logging is not taking place, the number of log records that will be produced due to an INSERT, UPDATE, or DELETE, will loosely correspond to the number of rows being affected, in each index being touched by the update plan. Understanding how this works becomes very useful when monitoring large ETL processes. It’s often the case that it’s possible to make a fairly precise estimation about how many rows will be touched by each phase of a data load. By taking that number into account and taking a look at the number of indexes in the query plan, estimating how much longer the ETL will take becomes a simple matter of querying a few times to understand the rate at which rows are being written, and then doing a bit of multiplication. + +As a final note, it's important to realize that there may be log writes in *tempdb* that cannot be reported by Who is Active due to the way the DMVs treat nested internal transactions. These writes are due to query processor operations such as sorts, hashes, and spools, and will be reflected in Who is Active's output in the [tempdb_allocations] column. + +------ +Prior: [Planning for Success](11_planning.md) Next: [How Queries Are Processed](13_queries.md) +------ diff --git a/Docs/13_queries.md b/Docs/13_queries.md new file mode 100644 index 0000000..a54019d --- /dev/null +++ b/Docs/13_queries.md @@ -0,0 +1,73 @@ +# sp_whoisactive: How Queries Are Processed + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [The Almighty Transaction](12_transaction.md) Next: [Blocking, Blockers, and Other B Words](14_blockers.md) +------ + +**This article and the next take a take a break from Who is Active** to get into some important background information on how things work internally in the query processor. The DMVs—and, therefore, Who is Active—reveal fairly deep information about what’s going on with your query, but unless you understand the basics it’s going to be difficult to properly interpret that data. + +Most of the time when people teach this subject, they start off with an image like the following: + +![F13_01_boring](image/F13_01_boring.jpg) + +**That’s all well and good, except that it’s a bit on the dull side.** + +A nicer approach, in my opinion, is to teach this topic using a metaphor. And others seem to agree: Joe Sack uses a grocery store checkout line, Rob Farley created a metaphor involving airport check-in lines, and Robert Davis has recommended something to do with running out of toilet paper while using a public bathroom stall. (I didn’t ask.) + +**My metaphor is a diner**. The Resource Diner. It’s open 24 hours a day, 7 days a week (99.999% of the time, when the staff is doing its job properly), and it’s where workers go when they’re hungry. And workers are *always* hungry. But I’m getting ahead of myself a bit. + +![F13_01_Restaurant](image/F13_01_Restaurant.jpg) + +**It all begins with a query**. You send it to SQL Server, and it gets parsed, and bound, and optimized, and the output is a plan. A plan is a program for the query processor to run. The query processor needs to run this program on physical CPUs, using physical memory, and perhaps physical disk drives. But it doesn’t talk to these various physical components directly; rather, it uses abstractions. Most of these abstractions are provided by SQLOS, some by the storage engine, and still others by the Windows kernel itself. One of the main abstractions is that over operating system threads. The abstracted version is called a *worker*, and the worker executes *tasks*, which are essentially segments of the plan. A serial plan will have one task, and a parallel plan may have many. (See my [SQL University](http://dataeducation.com/sql-university-parallelism-week-introduction/) series for more information.) + +**While executing a task, the worker can really do only two things**: consume CPU time, and wait for some resource that it needs to use in order to consume CPU time. + +**And that is why workers are always hungry**. + +When a worker gets hungry, it visits the restaurant. It already knows what it wants to eat, so it doesn’t bother with the menu. It goes straight to the cashier and makes its request. + +![F13_02_cashier](image/F13_02_cashier.jpg) + +“I’ll have a page lock with extra schema stability on the side.” + +Sometimes the resource is already available, sitting there warming under the heat lamps. The worker can take it and get right back to consuming CPU time. + +![F13_03_HeatLamp](image/F13_03_HeatLamp.jpg) + +But sometimes the resource isn’t ready yet. Perhaps an exclusive lock on the resource is being held by someone else, or perhaps the page needs to be read off the disk, or perhaps some memory needs to be granted. + +![F13_04_empty](image/F13_04_empty.jpg) + +When a worker needs a resource, it can’t go off and do something else in the meantime. It wants to consume the resource it needs. So the “order” is sent off to be prepared, and meanwhile the worker has to *wait*. + +![F13_05_cooking_waiting](image/F13_05_cooking_waiting.jpg) + +Eventually, the worker is called over the loudspeaker. “Order up! One page lock, extra schema stability on the side!” (This is called being *signaled*.) The worker can now get its resource from the cashier! But lo and behold, other workers have come into the restaurant while our worker was waiting. They’re getting orders from the cashier. So our worker will have to wait some more. This is known as being in the *runnable queue*. + +![F13_06_cashier](image/F13_06_cashier.jpg) + +After a long and arduous wait, our heroic worker finally gets its resource and can chow down. Ahh, life is good. + +![F13_07_yum](image/F13_07_yum.jpg) + +Now that the metaphor has been laid out, let’s take another look at the oh-so-dull technical image from above: + +![F13_01_boring](image/F13_01_boring.jpg) + +Here’s what’s going on: + +- Time 0 is when the worker gets hungry. It needs a resource. Let’s say that it’s a certain page. + - If it’s already available (e.g. the page is in the buffer cache), there is no wait. The worker can immediately continue its work. + - If the page isn’t in the cache, it needs to be read off disk. The worker stops working, gets off of its scheduler, and starts waiting. + +- Time 1 is when the food is ready. The page has now been read off of the disk. The worker is ready to get back on the scheduler and continue its work, but some other process may have started working on the scheduler in the meantime. And there may be a line of other workers, all waiting for the scheduler. If there is a line, the worker has to wait yet again—but this isn’t a *resource wait* anymore. It’s now a *signal wait*. + +- Time 2 is when the worker finally gets back to the cashier. It takes its resource and gets to work again on the scheduler. + +The important intervals here are between Time 0 and Time 1 (resource wait time) and between Time 1 and Time 2 (signal wait time). The resource wait time is impacted by however long it takes to read the page off of the disk, grant the memory, fulfill the lock request, or whatever. The signal wait time is almost entirely impacted by how busy the scheduler happens to be. + +------ +Prior: [The Almighty Transaction](12_transaction.md) Next: [Blocking, Blockers, and Other B Words](14_blockers.md) +------ diff --git a/Docs/14_blockers.md b/Docs/14_blockers.md new file mode 100644 index 0000000..864b2b4 --- /dev/null +++ b/Docs/14_blockers.md @@ -0,0 +1,113 @@ +# sp_whoisactive: Blocking, Blockers, and Other B Words + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [How Queries Are Processed](13_queries.md) Next: [Seeing the Wait That Matters Most](15_waits.md) +------ + +[The prior article](13_queries.md) was an introduction to query processing and wait states. **This article looks at the most famous and most feared wait of them all: blocking!** + +The word “blocking” has such a bad connotation, it’s almost at a disadvantage right off the bat. It sounds as though someone has started up some query for the express purpose of getting in your way. They’re letting that query run, and making sure that it’s keeping its transaction open as long as possible, so as to keep your query from doing the work it needs to do. Blocking! + +The reality is that blocking is nothing more than a specific type of wait. Just like a disk wait, or a memory grant wait, or any of the many other wait types. Blocking is a wait for a lock. And that lock was probably taken for a good reason. Most, believe it or not, are. Locks are there to protect our data from various forms of corruption and inconsistency, and to help maintain those ACID properties that we all know and love. Blocking is a natural side-effect. It’s not only common, it’s also very much to be expected. + +**What we need to be concerned with is not blocking, but rather excessive blocking**. This means extended blocking waits that really are slowing down your queries and causing work to grind to a halt. While this may seem obvious to most readers, the fact is that it's quite common to see DBAs to get way too caught up in looking for blocking, in an attempt to somehow eliminate it altogether. That's simply not possible, so my recommendation is to relax and try to focus on outlier conditions. + +Block monitoring via DMVs can be done in various places. The *sysprocesses*, *sys.dm_exec_requests*, and *sys.dm_os_waiting_tasks* views all expose information about blocking. But the information is at different levels of granularity, and it can be interpreted in various ways. Sometimes in the wrong way. + +To illustrate this issue, we first need to create a blocking situation. I like to use *AdventureWorks*: + +```sql +USE AdventureWorks +GO + +BEGIN TRAN + +UPDATE TOP(10) Sales.SalesOrderDetail +SET OrderQty += 7 +GO +``` + +Next—in a new window—we can query the *SalesOrderDetail* table. This will, of course, create blocking: + +```sql +SELECT + * +FROM Sales.SalesOrderDetail +``` + +I’ve set up the blocker transaction on session 53, and the blocked session is 54. And when I ask the DMVs for more information, the results are not surprising... + +```sql +SELECT + blocking_session_id +FROM sys.dm_exec_requests +WHERE + session_id = 54; + +SELECT + blocking_session_id +FROM sys.dm_os_waiting_tasks +WHERE + session_id = 54; +``` + +![F14_53_blocker1](image/F14_53_blocker1.jpg) + +**Things get quite a bit more interesting when parallelism is involved**. The following query will go parallel on most test systems: + +```sql +SELECT TOP(1000) + * +FROM Sales.SalesOrderDetail +ORDER BY + SalesOrderDetailId DESC +``` + +Running this on session 54 creates blocking, just like the previous query. But re-running the two DMV queries from above yields completely different results: + +![F14_53_not_blocker](image/F14_53_not_blocker.jpg) + +The *sys.dm_exec_requests* view now says that there is no blocking. And the *sys.dm_os_waiting_tasks* view now says that session 54 is blocking itself, except when it’s being blocked by session 53. Clearly, something is amiss. + +We can start to understand the situation in the *sys.dm_exec_requests* view by adding a few additional columns: + +```sql +SELECT + exec_context_id, + blocking_session_id, + blocking_exec_context_id, + wait_type +FROM sys.dm_os_waiting_tasks +WHERE + session_id = 54; +``` + +![F14_53_more_info](image/F14_53_more_info.jpg) + +Each of the rows above represents a different execution context ID (a way of identifying a worker thread; I’ve also included the [waiting_task_address] column, which can be used for the same purpose) that is being used by the query processor to evaluate the query plan. Seven of the eight threads are waiting on *CXPACKET*—the special exchange iterator wait used in all parallel plans. These threads are waiting on rows from an upstream parallel scan. And most of the threads are being “blocked” by other threads that are associated with the same request. This is not true blocking in the usual sense of the term. It’s simply multi-threaded synchronization, but the DMVs are not quite granular enough to report things that way. + +**Only execution context 2 is actually being blocked**. (We can see the lock wait, *LCK_M_S*.) The rest can be said to be blocked as well, but only virtue of the execution context chain. Any thread from a given session reported as “blocking” a thread from the same session should never be a concern to us as SQL Server end users, unless there is a bug in the product. And while bugs do happen from time to time, that’s certainly not the case here. + +Execution context 0 in this and other parallel plans is special. It’s the coordinator thread (a.k.a. parent thread, a.k.a. dispatcher thread, a.k.a. root thread) that spawns the other worker threads and then waits for them to complete. It’s not blocked directly, and the DMV reports that it is waiting on *CXPACKET*. Let’s take another look at *sys.dm_exec_requests*, this time with more columns: + +```sql +SELECT + blocking_session_id, + wait_type, + task_address +FROM sys.dm_exec_requests +WHERE + session_id = 54; +``` + +![F14_53_requests_more_info](image/F14_53_requests_more_info.jpg) + +Using the [task_address] column and comparing it to the various task addresses in the *sys.dm_os_waiting_tasks* view, we can get to the bottom of the mystery. The reported address matches that of execution context 0 above. So we can conclude that ***sys.dm_exec_requests* is giving us information only about the coordinator thread**. And it is correctly reporting that there is no blocking *on that thread.* Unfortunately, the nasty side-effect of correctness in this case is that we miss the fact that there is indeed blocking *for the request as a whole*. + +Making Who is Active behave properly in this case was a big win—it’s the difference between seeing and being able to understand blocking in a straightforward manner and not seeing it at all. Over the next couple of days I will describe how these situations are handled in the stored procedure. + +------ +Prior: [How Queries Are Processed](13_queries.md) Next: [Seeing the Wait That Matters Most](15_waits.md) +------ diff --git a/Docs/15_waits.md b/Docs/15_waits.md new file mode 100644 index 0000000..0f95f12 --- /dev/null +++ b/Docs/15_waits.md @@ -0,0 +1,37 @@ +# sp_whoisactive: Seeing the Wait That Matters Most + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Blocking, Blockers, and Other B Words](14_blockers.md) Next: [Seeing All of the Waits](16_morewaits.md) +------ + +The prior two articles delved into the internal workings of the query processor, specifically around tasks and the work-wait lifecycle. **Understanding how tasks work is a key prerequisite for understanding some of the data most useful that Who is Active can return**—so if you haven’t read those posts, go do that before reading this one. + +The “waits and queues” performance tuning methodology involves tuning a system by looking at what processes are waiting on, rather than by focusing solely on performance counters and similar metrics. Waits and queues is generally applied in the SQL Server world on an instance-global level, using the *sys.dm_os_wait_stats* view. And while this can give you some insight into what your instance is spending its time doing, I’m personally much more interested in the real-time wait stats provided by some of the other DMVs—and that is, of course, the data that Who is Active returns. + +Yesterday’s post was all about blocking, and the fact that a given request can have multiple waits reported by the DMVs. In the example I used for the post, most of these waits were *CXPACKET*. But in real-world queries there can be numerous different waits, all happening on different tasks that are busy doing various things on behalf of the query. + +Initial versions of Who is Active returned information about all of the waits reported in the waiting tasks view, but I found that this was a bit too heavy in most cases. Not only did it slow down the stored procedure, but it also delivered a lot more information than many people were equipped to deal with. So at some point I introduced the current default model, the “lightweight” waits collection mode. **This mode returns, at most, information about one wait per request**; the most important wait, per the logic I’ve implemented. Here’s how it works: + +- All of the waits are evaluated and prioritized +- *CXPACKET* waits—the parallelism waits—are discarded +- Blocking waits get top priority +- After that, priority is given to waits that have been outstanding for the longest amount of time +- Any remaining ties are broken by ordering by the blocking session ID + +**The most controversial part of this system, based on the number of questions I’ve received, seems to be the removal of the *CXPACKET* waits**. But for me it’s a relatively straightforward move. *CXPACKET* waits mean parallelism. Parallelism means *CXPACKET* waits. The coordinator thread will *always* wait on *CXPACKET* while the worker threads are busy. That’s just how the system is designed. Therefore, the longest waits for any given plan that is being processed in parallel will be waits on *CXPACKET*. Does that mean there’s a problem? No—not unless you feel that parallelism itself is a problem (and I most certainly do not). + +**If you have a parallel query that’s taking a long time, it's probably not due to excessive waiting on *CXPACKET***. While there is such a thing as a query that probably shouldn’t be using parallelism, there are no simple metrics or formulas that will help you figure that out based on the *CXPACKET* wait time. It’s really something that needs to be addressed on a case-by-case basis. A much better idea is to look at the *other* threads—those that aren’t waiting on *CXPACKET*—to see what they’re waiting on. The threads waiting on *CXPACKET* are waiting for data from those other threads, so it’s by looking at the other threads that you’ll find the actual performance culprits. + +For these reasons, *CXPACKET* is discarded in the default waits collection mode. After getting rid of those waits, blocking waits are sent to the top of the list. Heavy blocking is certainly something that you want to be aware of—it absolutely will slow down your queries (and maybe even cause them to grind to a halt), and information about blocking is one of the core things that Who is Active is designed to show. + +Assuming that there is no blocking, or even if there is blocking on two different threads and a priority is needed, the longer waits get pushed to the top. The reasoning is simple: longer waits slow down your query more than shorter waits. And you want to see the worst culprits when looking at wait information. + +All of this sorting results in a single wait (or, on very rare occasions, multiple waits, in which case the tie is broken using a row number). Unlike the wait information in *sys.dm_exec_requests*, this wait does not arbitrarily correspond to the coordinator thread. It is instead the one wait that is most important for you to focus on at the time the data was collected. The wait that actually matters. **Here is the blocking situation from yesterday as viewed through the eyes of Who is Active’s lightweight waits collection mode**: + +![F15_53_is_blocked](image/F15_53_is_blocked.jpg) + +------ +Prior: [Blocking, Blockers, and Other B Words](14_blockers.md) Next: [Seeing All of the Waits](16_morewaits.md) +------ diff --git a/Docs/16_morewaits.md b/Docs/16_morewaits.md new file mode 100644 index 0000000..927545c --- /dev/null +++ b/Docs/16_morewaits.md @@ -0,0 +1,48 @@ +# sp_whoisactive: Seeing All of the Waits + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Seeing the Wait That Matters Most](15_waits.md) Next: [Is This Normal?](17_normal.md) +------ + +Who is Active’s default lightweight waits collection is designed to show you the most important wait that’s currently slowing down your request. But in doing so it hides a lot of information. **Who is Active is capable of showing you information about all of the waits that are currently pending on behalf of your request**. All you need to do is modify the *@get_task_info* parameter... + +```sql +EXEC sp_WhoIsActive + @get_task_info = 2 +``` + +This causes the single wait described in the [prior article](15_waits.md) (the blocking wait, *LCK_M_S*) to become a report about all nine waits (see the [article on blocking](14_blockers.md) for background information): + +![F16_lots_of_info](image/F16_lots_of_info.jpg) + +We now see the full picture, including both the lock wait and all of the *CXPACKET* waits. Each wait type is broken out and accompanied by information on how many waits there are, and how long the waits have been outstanding. In this case we have a single task that is waiting on *LCK_M_S* and eight tasks waiting on *CXPACKET*. + +Depending on how many tasks are waiting for each wait type, Who is Active breaks out the times as follows: + +- One waiting task: *(1x: MINms)[wait_type]* where MINms is the number of milliseconds that the task has been waiting +- Two waiting tasks: *(2x: MINms/MAXms)[wait_type]* where MINms is the shorter wait duration between the two tasks, and MAXms is the longer wait duration between the two tasks +- Three or more waiting tasks: *(Nx: MINms/AVGms/MAXms)[wait_type]* where Nx is the number of tasks, MINms is the shortest wait duration of the tasks, AVGms is the average wait duration of the tasks, and MAXms is the longest wait duration of the tasks + +In this case the *LCK_M_S* wait has been pending for just over 412 seconds. The exchange waits all started building up just after the block situation started, so the minimum and average wait times for those are within a few milliseconds of the wait time for the blocking wait. + +**In addition to the pending wait time, some additional information gets shipped along with three wait categories**: + +- For waits matching the pattern *PAGE%LATCH%* (*PAGEIOLATCH* or *PAGELATCH*), the page number is evaluated to find out if it is one of the “special” page types: PFS, GAM, SGAM, DCM, or BCM. If so, the wait is flagged as being on one of those pages. (The page type will appear in parenthesis after the wait type; if it’s not one of those page types, it will be listed as ***). A post later this month will explain why this is important. +- Waits matching the pattern *LATCH[_]%* are latch waits on a specific latch class. Who is Active reports the latch class along with the wait. (Again, the additional information latch class will appear in parenthesis.) +- *CXPACKET* waits ship with a node identifier, corresponding to a node in the query plan. The node ID is included after the wait, separated by a colon. In the above image, the *CXPACKET* waits are all occurring on node 3 in the query plan. As with the “special” pages, I’ll cover this feature in more detail in a later post. + +**A bit more information is available when using *@get_task_info* = 2**. Three additional columns are added to the Who is Active output, which apply to active requests (all three will be NULL for sleeping sessions). + +![F16_task_info](image/F16_task_info.jpg) + +- [tasks] is the number of active tasks currently being used by the request. +- [context_switches] is the number of context switches that have been done for all of the tasks currently being used by the request. This number is updated in real time and can give a closer approximation of CPU utilization when evaluating requests that are being processed using a parallel plan. +- [physical_io] is the number of physical I/O requests that have been issued on behalf of all of the tasks currently being used by the request. Again, this number is updated in real time. + +**The key term for all of these is “real time”**—even for parallel plans. This is in stark contrast to the [CPU], [reads], [writes], and [physical_reads] columns that are in the default output, and which are not updated in real time once more than one thread is involved. Unfortunately, real time also has its drawbacks. As the various tasks that are working on behalf of the query begin finishing their work, the numbers will no longer be cumulative to the query, and will cease to make a whole lot of sense. That’s a small price to pay, in my opinion, for timely information when looking at active queries. + +------ +Prior: [Seeing the Wait That Matters Most](15_waits.md) Next: [Is This Normal?](17_normal.md) +------ diff --git a/Docs/17_normal.md b/Docs/17_normal.md new file mode 100644 index 0000000..d694490 --- /dev/null +++ b/Docs/17_normal.md @@ -0,0 +1,81 @@ +# sp_whoisactive: Is This Normal? + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Seeing All of the Waits](16_morewaits.md) Next: [Getting More Information](18_moreinfo.md) +------ + +#### There you are, minding your own business (and that of everyone else on your server) checking out activity with Who is Active. + +Some stored procedure is running for what seems like an excessive amount of time—but you’re not quite sure. Should you take a closer look? + +The answer can only be my favorite two-word phrase: It Depends. + +If a system has been live for quite some time and users are happy enough with performance, I tend to not get too caught up in proactively trying to find things to tune. If, on the other hand, users are complaining, or something has just started taking a lot longer than it used to, then it’s time to step in and do some tuning. + +**Today’s post is about helping you figure out whether you’ve identified one of these latter cases: a query that was running fine, but is suddenly not doing so well**. This can happen due to any number of root causes, the most common of which are outdated statistics and parameter sniffing. Actually fixing the problem is beyond the scope of this post, but identifying it is half the battle. + +Who is Active’s *@get_avg_time* option is designed for this scenario. When enabled, a new column is added to the Who is Active output, [dd hh:mm:ss.mss (avg)]. This column reflects the average run time—if it’s available—of the statement that your request is currently working on. The idea is that if you’re not sure whether the current run time is an anomaly, you can compare it to how long previous runs have taken to figure out whether you have reason for concern. Note that this is only useful if the server happens to have cached statistics about prior runs. If the cache has been cleared recently due to a reboot, memory pressure, or someone changing the server configuration options, all bets are off. + +To see the feature in action, we can simulate a basic parameter skew issue. Set up the following stored procedure in *AdventureWorks*: + +```sql +USE AdventureWorks +GO +CREATE PROC #sniff_test + @min_ProductID INT, + @max_ProductID INT +AS +BEGIN + SELECT + p.ProductID, + COUNT(th.TransactionID), + COUNT(sod.SalesOrderID) + FROM Production.Product AS p + LEFT OUTER JOIN Production.TransactionHistory AS th ON + th.ProductID = p.ProductID + LEFT OUTER JOIN Sales.SalesOrderDetail AS sod ON + sod.ProductID = p.ProductID + WHERE + p.ProductID BETWEEN @min_ProductID AND @max_ProductID + GROUP BY + p.ProductID +END +GO +``` + +Now exercise the procedure a few times to get a baseline: + +```sql +EXEC #sniff_test + @min_ProductID = 1, + @max_ProductID = 700 +GO 100 +``` + +Once the baseline has been established you’ll have a nice set of statistics recorded in the cache. Changing the arguments ever-so-slightly will have an enormous impact on the run time: + +```sql +EXEC #sniff_test + @min_ProductID = 1, + @max_ProductID = 800 +GO +``` + +While that’s churning away, bring up a new window and run Who is Active using the *@get_avg_time* option. + +```sql +EXEC sp_WhoIsActive + @get_avg_time = 1 +``` + +The result will be something like the following: + +![F17_01_avg1](image/F17_01_avg1.jpg) + +From these results we can see that when I ran Who is Active the procedure had already been running for over two seconds. But the average time is a mere 59 milliseconds. Clearly, something is amiss. (And indeed it is: both an inappropriate plan and a *ProductID* range with a lot more information than the prior range that was used.) + +------ +Prior: [Seeing All of the Waits](16_morewaits.md) Next: [Getting More Information](18_moreinfo.md) +------ diff --git a/Docs/18_moreinfo.md b/Docs/18_moreinfo.md new file mode 100644 index 0000000..8edc341 --- /dev/null +++ b/Docs/18_moreinfo.md @@ -0,0 +1,51 @@ +# sp_whoisactive: Getting More Information + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Is This Normal?](17_normal.md) Next: [Why Am I Blocked?](19_whyblocked.md) +------ + +#### Sometimes you just need more. + +With over 20 columns in the default output plus several more than can be dynamically enabled and disabled, Who is Active was already overwhelming enough for certain users. But requests kept pouring in for various additional information—metrics to help debug trickier situations and edge cases. + +Rather than cluttering the output, I decided to create a single, special-purpose column for everything that’s not quite important enough to be on its own in the output. The [additional_info] column is an XML column that returns a document with a root node called . **What’s inside of the node depends on a number of things**, but by default you can expect to see: + +- text_size +- language +- date_format +- date_first +- quoted_identifier +- arithabort +- ansi_null_dflt_on +- ansi_defaults +- ansi_warnings +- ansi_padding +- ansi_nulls +- concat_null_yields_null +- transaction_isolation_level +- lock_timeout +- deadlock_priority +- row_count + +Rather than repeat the documentation, I’ll point you to the [BOL entry for sys.dm_exec_requests](http://msdn.microsoft.com/en-us/library/ms177648.aspx) for information about what all of these mean. Most of them are various settings that can be manipulated by a given user, batch, or stored procedure. They impact the results of a query and, in some cases, its plan. So it’s a good idea to be able to pull them up when needed. + +Beyond these, the [additional_info] column might also contain various other pieces of information, depending on which options are selected and what happens to be running. For example, **if a SQL Agent job is running [additional_info] will be populated with**: + +- job_id: the identifier for the job in MSDB +- job_name: the name of the job, from MSDB +- step_id: the identifier for the job step in MSDB +- step_name: the name of the job step, from MSDB +- msdb_query_error: included when an error occurs that renders Who is Active unable to resolve the job and step names + +This article is just a quick overview; I’ll cover other things you can expect to see in [additional_info] in a later article. In the meantime, **how do you get all of this information?** Simple: + +```sql +EXEC sp_WhoIsActive + @get_additional_info = 1 +``` + +------ +Prior: [Is This Normal?](17_normal.md) Next: [Why Am I Blocked?](19_whyblocked.md) +------ diff --git a/Docs/19_whyblocked.md b/Docs/19_whyblocked.md new file mode 100644 index 0000000..0898c1c --- /dev/null +++ b/Docs/19_whyblocked.md @@ -0,0 +1,63 @@ +# sp_whoisactive: Why Am I Blocked? + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Getting More Information](18_moreinfo.md) Next: [The Node Knows](20_node.md) +------ + +**Debugging a blocking situation can be a complex process**. First you need to figure out who’s doing the blocking, and who’s getting blocked. Next—before you can actually debug things—you need to figure out what the lock is that’s actually causing the blocking to occur. + +This second phase has been known to cause many a DBA to rip out numerous hairs. First comes a visit to the locks DMV, followed by an extended period of research. What is a [resource_associated_entity_id]? Does that have any bearing on the [request_owner_lockspace_id]? And do you even care? If you’re anything like me, most of the time you just want to move on with life. + +**Who is Active solves this problem in two distinct ways**, the first of which I’ll cover in today’s post, and the second a few posts down the road. Which method you choose depends on how much context you need to solve the problem at hand, and how much pressure you’re willing to put on your SQL Server instance. Today’s method is much lighter weight in terms of resource consumption and, in many cases, elapsed time. + +Creating a blocking situation is easy enough... In one window do: + +```sql +USE AdventureWorks +GO + +BEGIN TRAN +GO + +UPDATE TOP(10) Sales.SalesOrderDetail +SET + OrderQty += 7 +GO +``` + +And in a second: + +```sql +USE AdventureWorks +GO + +SELECT * +FROM Sales.SalesOrderDetail +GO +``` + +Who is Active figures things out easily enough in its default mode: + +![F19_01_blocked](image/F19_01_blocked.jpg) + +**...but what if things weren’t quite so cut-and-dry and you needed a bit more information?** In this case, you could enable two options that have been covered in prior articles: *[@get_task_info = 2](16_morewaits.md)* and *[@get_additional_info = 1](18_moreinfo.md)*. Who is Active uses these two options together to populate the [additional_info] column with information about what object is actually causing the blocking situation to occur: + +```sql +EXEC sp_WhoIsActive + @get_task_info = 2, + @get_additional_info = 1 +``` + +![F19_02_results](image/F19_02_results.jpg) + +Clicking on the [additional_info] column for the blocked session reveals... + +![F19_02_additional_info](image/F19_02_additional_info.jpg) + +...full information about the blocked object. This particular lock is a page lock on the Sales.SalesOrderDetail table (go figure). Information can be resolved for virtually all types of locks, and generally speaking this mode does the work extremely quickly, so it should not add a lot of overhead to your monitoring sessions. + +------ +Prior: [Getting More Information](18_moreinfo.md) Next: [The Node Knows](20_node.md) +------ diff --git a/Docs/20_node.md b/Docs/20_node.md new file mode 100644 index 0000000..17eb12d --- /dev/null +++ b/Docs/20_node.md @@ -0,0 +1,88 @@ +# sp_whoisactive: The Node Knows + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Why Am I Blocked?](19_whyblocked.md) Next: [Analyzing Tempdb Contention](21_tempdb.md) +------ + +**Query plans are packed with information about what’s going to happen, or what has happened.** But they’re markedly quiet about what *is happening*. + +This is probably best illustrated with an example. Consider: you’re sitting there at your desk one morning, enjoying a nice hot cup of coffee, when the phone rings. It’s Steve, the harried middle manager who sits on the 2nd floor. “Help!” Steve shouts into the phone, making you flinch and immediately move the headset away from your ear. “My report has been running for 10 minutes! I have a meeting in three minutes! Is it going to finish?” + +You calmly open Management Studio, fire up Who is Active, and glance at the various columns. No blocking. No extreme waits. Nothing too interesting in the plan. Just a big query chugging along. + +At this point there’s really not much you can do. But **there is one hint that *might* help give you some more insight**. Who is Active collects, along with *CXPACKET* waits, a node identifier. These are displayed along with the wait when *@get_task_info = 2* is used. This can help you figure out approximately what your plan is up to *right now*. + +Too see this in action, first create a blocking situation so that we have something to look at: + +```sql +USE AdventureWorks +GO + +BEGIN TRAN +GO + +UPDATE TOP(10) Sales.SalesOrderDetail +SET + OrderQty += 7 +GO +``` + +Next, in a new window, fire up the following query: + +```sql +USE AdventureWorks +GO + +SELECT + * +FROM +( + SELECT + sh.*, + sd.ProductId, + ROW_NUMBER() OVER + ( + PARTITION BY sd.SalesOrderDetailId + ORDER BY sd.ProductId + ) AS r + FROM + ( + SELECT TOP(1000) + * + FROM Sales.SalesOrderDetail + ORDER BY + SalesOrderDetailId DESC + ) AS sd + INNER JOIN Sales.SalesOrderHeader AS sh ON + sh.SalesOrderId = sd.SalesOrderId +) AS s +WHERE + s.r = 1 +GO +``` + +Assuming that you have a multicore machine, the plan for this query will have a few different parallel sections. Which is what we need for *CXPACKET* waits. Let’s see what Who is Active has to say about the situation: + +```sql +EXEC sp_WhoIsActive + @get_task_info = 2, + @get_plans = 1 +``` + +![F20_01_CXPACKETs](image/F20_01_CXPACKETs.jpg) + +The query has 10 tasks. One of them waiting on a lock; we’ll ignore that one since we’ve created the lock to “pause” things in this case. The other nine are all waiting on *CXPACKET* waits—but there are two different groups. The first group consists of eight tasks, all waiting on node 17. The second group has only a single task, and it’s waiting on node 0. + +So what are these nodes? Bring up the plan, hover over any of the iterators therein, and you’ll see: + +![F20_02_node_id](image/F20_02_node_id.jpg) + +**Every iterator in the plan has an associated node identifier**. These range from 0—for the leftmost node in the plan—on up, as you move to the right. *CXPACKET* waits are associated with exchange (parallelism) iterators, and the wait information includes the actual node identifier from the plan. By using this information you can begin to understand the flow of data through your larger plans, as task waits move from node to node. + +This is certainly not a perfect solution, and chances are very good that you won’t be able to give Steve from the 2nd floor the exact amount of time remaining. But every bit of information helps, and in this case you may be able to come up with a reasonable estimate. Even if he ends up running to the meeting with only half of the report printed. + +------ +Prior: [Why Am I Blocked?](19_whyblocked.md) Next: [Analyzing Tempdb Contention](21_tempdb.md) +------ diff --git a/Docs/21_tempdb.md b/Docs/21_tempdb.md new file mode 100644 index 0000000..c3d82d6 --- /dev/null +++ b/Docs/21_tempdb.md @@ -0,0 +1,44 @@ +# sp_whoisactive: Analyzing Tempdb Contention + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [The Node Knows](20_node.md) Next: [The Key to Your Locks](22_locks.md) +------ + +#### *Tempdb*. Everyone’s favorite shared bottleneck. + +The funny thing about *tempdb* is that it’s not heavily used by every query. It’s only really hammered by the very *biggest* or *most frequent* queries. The queries where performance really matters. And of course, that makes the situation all the worse. When *tempdb* is a problem, it’s a *major problem*. + +A common cause of *tempdb* issues is *latch contention*. This occurs due to three “special” page types: GAM (Global Allocation Map), SGAM (Shared Global Allocation Map), and PFS (Page Free Space). Each of these pages (sometimes many of each) exist in all database files, and they are responsible for helping to identify where incoming data can be written in the physical file. For complete background, [read this post by Paul Randal](https://www.sqlskills.com/blogs/paul/the-accidental-dba-day-27-of-30-troubleshooting-tempdb-contention/). + +Whenever a process needs to update one of these special pages, a *latch* is taken. A latch can be thought of as a kind of very lightweight lock; it’s designed for synchronization and is intended to be quickly turned on, and then just as quickly turned off after it’s no longer needed. The problem occurs when lots of processes happen to hit the SQL Server instance at the exact same time, and they all need to find a place to store some data. Suddenly, there are numerous outstanding latch requests. They start queuing up, and before you know it the last one in line has been waiting for seconds—and not doing any work at all in the meantime. + +Seeing this in action is quite simple. Create a bunch of temporary tables, in a very short period of time. I like to demo this using [SQLQueryStress](https://www.microsoft.com/en-us/p/sqlquerystress/9n46qj5sbgkb?activetab=pivot:overviewtab). Ideally you should do this kind of test on a server with only a single *tempdb* data file, to really highlight the issue. Here’s the code to run: + +```sql +SELECT TOP(10000) + a.* +INTO #x +FROM + master..spt_values a, + master..spt_values b +``` + +20 or so concurrent threads should do it. Hit the start button in your load tool, wait a few seconds, run Who is Active, and you’ll see something similar to: + +![F21_01_latch_waits](image/F21_01_latch_waits.jpg) + +**See those *PAGELATCH* waits?** They’re all on the same resource: PFS pages, in *tempdb* file ID 1. The format for *PAGELATCH* and *PAGEIOLATCH* waits is: *\[wait_type]:\[database_name]:\[file_id](page_type)*. Who is Active can decode the page types for GAM, SGAM, PFS, DCM (Differential Change Map), and BCM (Bulk Change Map) pages. For any other page, the page type will be an asterisk (*). + +These waits are all on *update* (UP) latches, but it's also quite common to see *exclusive* (EX) latches when this problem occurs + +**Fixing this problem is amazingly simple**: just create more *tempdb* files! When you create additional *tempdb* files—as long as they’re equally sized—SQL Server will automatically balance incoming requests across the multiple files. Since each file maintains its own PFS, GAM, and SGAM information, the contention will be eliminated. + +How many files should you create? Well, that depends on your workload. I take a simple approach: start with a number of files equal to one quarter to one half of the number of logical schedulers. If the contention goes away (i.e. Who is Active is no longer showing *PAGELATCH* waits on these special pages in *tempdb*), stop there. Otherwise, keep increasing the number of files until the contention does go away. + +**Again: make sure to keep the files equally sized!** SQL Server’s algorithm is based on a *proportional fill* model, which means that if one file is bigger than the others it will be chosen more often. This will cause it to grow more quickly, which will cause it to be chosen more often, which will cause it to grow more quickly, which will keep compounding until your disk is full and your performance is back in the red zone. Not a good situation to get yourself into. Grow the files bigger than you need them at create time, and monitor to make sure things don’t get out of hand. + +------ +Prior: [The Node Knows](20_node.md) Next: [The Key to Your Locks](22_locks.md) +------ diff --git a/Docs/22_locks.md b/Docs/22_locks.md new file mode 100644 index 0000000..b4eb559 --- /dev/null +++ b/Docs/22_locks.md @@ -0,0 +1,47 @@ +# sp_whoisactive: The Key to Your Locks + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Analyzing Tempdb Contention](21_tempdb.md) Next: [Leader of the Block](23_leader.md) +------ + +**Blocking has been a theme of a [couple](14_blockers.md) of [prior](19_whyblocked.md) articles**. And that’s not even the end of it. Helping you find and properly evaluate blocking issues is a core part of Who is Active’s *raison d'être*. + +Behind every block is something causing the block. Something that, without which, there could be no block. And that thing is called a *lock*. + +Locks are synchronization objects. Their mission in life is not to give you headaches when dealing with blocking issues, but rather to help maintain the ACID properties that are a big part of the reason that DBMS technology is so popular. For locks in particular this means the “I” property: Isolation. (And, to a lesser extent, the "C" property: Consistency.) Locks keep readers from reading data that writers haven’t finished writing, and they keep writers from overwriting data as it’s being read or written by someone else. This is a good thing. Failure to take these kinds of precautions would result in chaos. And a lot of really bad data. + +When a DBA sees blocking, her first instinct is to eliminate it. Kill the blocker! Add a *NOLOCK* hint! Change the processes around! But blocking is not necessarily a bad thing. Blocking means that your data is being protected. Readers are getting consistent results. Writers aren’t overwriting each other. Everything is as it should be—even if your queries are waiting an inordinate amount of time for data. + +**When you see blocking, the correct move is not to eliminate it, but rather to *evaluate* it**. Figure out what’s causing the blocking. Figure out why (or whether) it’s necessary, and what the alternatives might be. Then—and only then—should you start killing sessions, adding hints, or taking similar action. + +Evaluating blocking can be a painful experience. The *sys.dm_tran_locks* view (formerly *syslockinfo*) contains a large number of columns. Many of these are numeric values that need to be referenced elsewhere in order to be meaningful to the average human. And even then, it’s simply not a very nice user experience... + +![F21_01_tran_locks](image/F21_01_tran_locks.jpg) + +**Glancing at this list of lock information, it’s impossible to tell what’s going on**. (The query I ran to pull up this list returned 2700 rows.) + +Who is Active solves this problem by putting locks into a somewhat more human-readable form: a custom XML format. The stored procedure does all of the work of going to the databases with locks and decoding the numbers. So instead of seeing something like *72057594038845440*, you’ll see something like *Sales.SalesOrderHeader*. Whether or not you think that XML in general is a very readable format, the fact that the various object names have been resolved for you makes it a lot better than a straight query against *sys.dm_tran_locks*. + +**To get lock information, use Who is Active’s *@get_locks = 1* option**. This will add a column called [locks] to the output. The column is typed as XML, and you can click on it to see the full contents. The document will have one root node per database in which there are locks. For the table listed above, the collapsed nodes look like this: + +![F21_02_locks_database](image/F21_02_locks_database.jpg) + +Under each database node is one node that represents locks on the database itself, and a node called *Objects* that contains subnodes for each object in the database that’s locked. These are grouped by object name and schema name: + +![F21_03_locks_object](image/F21_03_locks_object.jpg) + +Any given object can have multiple types of active locks issued against it at one time, so inside of the *Object* nodes are one or more *Lock* nodes: + +![F22_04_locks](image/F22_04_locks.jpg) + +This format allows for quick and simple exploration of the various locks that are active on behalf of your session. Each *Lock* node has an attribute called *request_status*. If its value is “GRANT,” the lock is held by the session. If its value is “WAIT,” the request is waiting to acquire the lock. + +A full description of the various lock types is well beyond the scope of this post, but most of them are documented in the [Books Online entry for sys.dm_tran_locks](http://msdn.microsoft.com/en-us/library/ms190345.aspx). + +**A cautionary note**: Using the *@get_locks* option can seriously slow down Who is Active. The *sys.dm_tran_locks* DMV is known to be one of the slowest DMVs, and in some cases it can hold a huge number of rows. I have seen numerous cases where a simple *SELECT ** against the DMV took 20 or more minutes to finish. When dealing with locks, which can change rapidly, that’s far too much elapsed time for the results to be meaningful. Before enabling full locks mode, I recommend trying [blocked object resolution](19_whyblocked.md) mode, which is designed to be a much lighter weight alternative. + +------ +Prior: [Analyzing Tempdb Contention](21_tempdb.md) Next: [Leader of the Block](23_leader.md) +------ diff --git a/Docs/23_leader.md b/Docs/23_leader.md new file mode 100644 index 0000000..8d53d07 --- /dev/null +++ b/Docs/23_leader.md @@ -0,0 +1,54 @@ +# sp_whoisactive: Leader of the Block + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [The Key to Your Locks](22_locks.md) Next: [The Output of Your Dreams](24_output.md) +------ + +**Oftentimes blocking situations are a bit more complex than one session blocking some other request**. In busy systems *blocking chains* can build up that include dozens or even hundreds of requests, all waiting on one another. And all are waiting as a result of one top-level blocker: the *block leader*. In many cases fixing the blocking problem means fixing whatever it is that the block leader is doing, so identifying it quickly is a key part of debugging blocking situations. + +Finding the block leader is a fairly simple process once you realize that **blocking is effectively a hierarchy**. The process involves starting with all of the requests that aren’t blocked and walking down the blocking chain until the leaf level is reached—blockees that lack any more downstream blockees. At each level, a number is recorded to figure out the blocking depth. As an added benefit, a second pass can be made to reverse the number at the end of the process—this shows the total number of downstream blockees for each blocker. + +While this is relatively easy to implement using a Common Table Expression, **it’s certainly not something that users should have to reinvent each time it’s needed**. So Who is Active exposes an option, *@find_block_leaders*, that does the work for you. This option adds a new column to the output, called [blocked_session_count], which reflects the total blockee count. Higher numbers mean more sessions blocked downstream; the sessions with the highest numbers are your block leaders, and these are the ones you want to focus on. + +To see this in a bit more detail, run the following batch in four sessions: + +```sql +USE AdventureWorks +GO + +BEGIN TRAN +GO + +UPDATE TOP(10) Sales.SalesOrderDetail +SET OrderQty += 7; +GO +``` + +Assuming that nothing else is running, the first session will complete. The other three will block. Who is Active reports this, of course, even in its default mode: + +![F23_01_blocked](image/F23_01_blocked.jpg) + +The initial update was run on session 53, which is blocking session 54. Both 55 and 56 are reported as blocked by 54, although in reality they’re being blocked indirectly by 53. This case, while more complex than most of the blocking examples used in this series, is still simpler than many of the things seen on average production systems. None the less, it’s enough to show the power of the Who is Active option that this post is about... + +```sql +EXEC sp_WhoIsActive + @find_block_leaders = 1 +``` + +![F23_02_leaders](image/F23_02_leaders.jpg) + +The [blocked_session_count] clearly shows which session is causing the issue in this case: 53 has three downstream blockees, whereas 54 has only two, and the other two sessions have none. + +In this case, because I happened to run the batches in the correct order, the data is returned by default with the block leader sorted on top. That may or may not always be the case in a real system, but it’s quite a useful thing when there are numerous active requests and you want the most important ones right at the top. To accomplish that, use the output ordering feature—which will be covered in detail in tomorrow’s post. + +```sql +EXEC sp_WhoIsActive + @find_block_leaders = 1, + @sort_order = '[blocked_session_count] DESC' +``` + +------ +Prior: [The Key to Your Locks](22_locks.md) Next: [The Output of Your Dreams](24_output.md) +------ diff --git a/Docs/24_output.md b/Docs/24_output.md new file mode 100644 index 0000000..44154bf --- /dev/null +++ b/Docs/24_output.md @@ -0,0 +1,78 @@ +# sp_whoisactive: The Output of Your Dreams + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Leader of the Block](23_leader.md) Next: [Capturing the Output](25_capturing.md) +------ + +#### Early in the process of creating Who is Active it became clear that there was no way everyone was going to agree. + +With each release I received requests to move some column so that it would show up on the lefthand side, or to change the sort order, or to make some other modification that someone felt was necessary to help them more easily digest the data. The problem: it was impossible to accommodate all of these requests. So I decided to go with a self-service model. + +In order to allow users to dynamically customize the output (without touching any code), the stored procedure exposes three options: *@output_column_list*, *@sort_order*, and *@format_output*. Each of these is discussed in the following sections. + +***@output_column_list*** controls not only whether or not certain columns will be shown in the output, but also the order in which the columns are displayed. The correct argument is a list of bracket-delimited column names (or partial names with wildcards). Delimiters are not necessary (use whatever delimiter you like, or none at all; they’re ignored). The key to successfully using this option is to remember that inclusion of columns in the output is additive: many columns (such as [additional_info]) are only added to the output if both the correct options are enabled for the stored procedure and the columns are included in the column list. If you start modifying the list and don’t take this into account, you may not see the columns you’re expecting when you go back later and start changing options. To keep things flexible, make sure to use wildcard columns, especially a generic wildcard (*[%]*) at the end. + +Using the column list can be as simple as specifying the exact columns you’re interested in: + +```sql +EXEC sp_WhoIsActive + @output_column_list = '[tempdb_allocations][tempdb_current]' +``` + +Notice that no delimiter is used here. Again, any extraneous text aside from the column specifiers is ignored, so the following call is equivalent: + +```sql +EXEC sp_WhoIsActive + @output_column_list = 'this[tempdb_allocations]is[tempdb_current]ignored' +``` + +Easier than specifying exact column names is to use wildcards that match the pattern of the columns you’re interested in: + +```sql +EXEC sp_WhoIsActive + @output_column_list = '[tempdb%]' +``` + +All three of these calls will yield the same output, similar to the following: + +![F24_01_column_list](image/F24_01_column_list.jpg) + +Of course, this will return *only* these two columns. Generally I’ll use the column list feature just to move things around so that I don’t have to do as much scrolling, and in those cases I almost always want everything else, too. That’s where the generic wildcard comes into play: + +```sql +EXEC sp_WhoIsActive + @output_column_list = '[tempdb%][%]' +``` + +![F24_02_all_cols](image/F24_02_all_cols.jpg) + +Now the *tempdb*-specific columns appear on the lefthand side, and all of the other columns follow, in a default order. + +**The next option we’ll cover is *@sort_order***. This option controls the order of the rows output by the stored procedure. Like *@output_column_list*, the input is a list of bracket-delimited column names. In this case, wildcards are not supported, but the keywords *ASC*[ENDING] and *DESC*[ENDING] are supported after the column name. + +The following call returns data sorted by [login_name] ascending (ascending is default, so the keyword is optional), with ties broken by [session_id] descending: + +```sql +EXEC sp_WhoIsActive + @sort_order = '[login_name][session_id] DESC' +``` + +As before, delimiters are optional and are ignored. Please note that the current betas of Who is Active have bug where multi-column sorts like this one are not properly honored. That issue will be fixed in the next version of Who is Active. + +Sorting is especially useful when doing any kind of comparison of the various requests currently running. I use it extensively in block leader mode ([blocked_session_count] DESC), and it is quite handy in delta mode—which will be covered in a post in a few days. + +**The final option this post will cover is *@format_output***. This one is based on the fact that Who is Active is designed to leverage SSMS as a “graphical user interface” of sorts. Query text is sent back in an XML format, numbers are formatted as right-justified strings, and elapsed time is formatted in the more easily-digestible [dd hh:mm:ss.mss] form. + +If you’ve been using Who is Active for a while you’ve probably noticed the right-justified numbers: + +![F24_03_right_justified](image/F24_03_right_justified.jpg) + +This format was suggested fairly early on by Aaron Bertrand, and is one of my favorite things about the stored procedure. It makes it much easier to pick out bigger numbers when you’re looking at a large set of data. By default, SSMS uses a non-fixed width font for grid results, so the default argument to *@format_output,* **1**, takes this into consideration. But some people—like Aaron Bertrand—change the SSMS settings and use a fixed width font instead. If you’re one of these people you can use an argument of **2** to get nicely-formatted numbers. If you don’t change the argument you might notice that the numbers don’t seem to properly line up when you’re working with a set of data containing numbers of greatly differing size. + +Still other people don’t like the right-justified numbers or are doing collection to a table (see tomorrow's post), and so formatting can be completely disabled by using an argument of **0**. It’s up to you... + +------ +Prior: [Leader of the Block](23_leader.md) Next: [Capturing the Output](25_capturing.md) +------ diff --git a/Docs/25_capturing.md b/Docs/25_capturing.md new file mode 100644 index 0000000..0a16db3 --- /dev/null +++ b/Docs/25_capturing.md @@ -0,0 +1,122 @@ +# sp_whoisactive: Capturing the Output + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [The Output of Your Dreams](24_output.md) Next: [Delta Force](26_delta.md) +------ + +[The prior article](24_output.md) was about configuring the output based on what *you* want to see. **This one is about taking that perfect output and persisting it.** + +There are many reasons that you might like to store the results of a Who is Active call to a table. Some of the real use cases that I’ve been told about by Who is Active users include: + +- Scheduled monitoring. Capturing the results of Who is Active calls in 5 or 10 minute intervals to see what’s happening on the database server throughout the day (or night) +- Using it as part of a build process, to verify that the correct things are happening in the correct order at the correct times +- Using it as part of an exception handling system that automatically calls Who is Active every time an error occurs, to snapshot the current state of the database instance + +And there are various other use cases in addition to these. The point is that there are a number of reasons that you might want to capture the output. + +**Unfortunately, it’s not as simple a task as you might think.** The first time I tried to make it work, I did something like: + +```sql +CREATE TABLE #output +( + ... +) + +INSERT #output +EXEC sp_WhoIsActive +``` + +This approach failed miserably. If you try it, as I did, you’ll see the following error message: + +```sql +Msg 8164, Level 16, State 1, Procedure sp_WhoIsActive, Line 3086 +An INSERT EXEC statement cannot be nested. +``` + +Who is Active uses a number of INSERT EXEC statements, and they cannot be easily changed or removed, so for a while it seemed like all was lost. After a bit of brainstorming, however, I realized that I could simply build yet another INSERT EXEC into Who is Active—one that will insert into a table of your choice. + +Of course, first you need a table. And if you’ve been reading this series you’re no doubt aware that the output shape returned by Who is Active is extremely dynamic in nature, and depends on which parameters are being used. So the first option I added was **a method by which you can get the output schema.** Two parameters are involved: If *@return_schema* is set to **1**, the schema shape will be returned in an *OUTPUT* parameter called *@schema*. This is best shown by way of example: + +```sql +DECLARE @s VARCHAR(MAX) + +EXEC sp_WhoIsActive + @output_column_list = '[temp%]', + @return_schema = 1, + @schema = @s OUTPUT + +SELECT @s +``` + +The idea is that you set up your Who is Active call with all of the options you’d like, then bolt on the *@return_schema* and *@schema* parameters. Here the column list is being restricted to only those columns having to do with *tempdb*. If you run this code, the *SELECT* will return the following result: + +```sql +CREATE TABLE ( [tempdb_allocations] varchar(30) NULL,[tempdb_current] varchar(30) NULL) +``` + +This result can be modified by replacing the “” placeholder with the name of the table you actually want to persist the results to. Of course this can be done either manually or automatically—after the call to Who is Active, the text is sitting in a variable, so a simple call to *REPLACE* is all that’s needed. That call could even be followed up by a call to execute the result and create the table... + +```sql +DECLARE @s VARCHAR(MAX) + +EXEC sp_WhoIsActive + @output_column_list = '[temp%]', + @return_schema = 1, + @schema = @s OUTPUT + +SET @s = REPLACE(@s, '', 'tempdb.dbo.monitoring_output') + +EXEC(@s) +``` + +**Of course now you probably want to put something into the table**. Crazy! To do this, drop the *@return_schema* and *@schema* parameters and replace them with *@destination_table*—the name of the table into which the results should be inserted: + +```sql +EXEC sp_WhoIsActive + @output_column_list = '[temp%]', + @destination_table = 'tempdb.dbo.monitoring_output' +``` + +Now the results of the call will be inserted into the destination table. Just remember that every time you change the Who is Active options, you’ll have to re-acquire the output shape. Even a small change, such as adding an additional column to the output list, will result in a catastrophic error. + +```sql +EXEC sp_WhoIsActive + @output_column_list = '[session_id][temp%]', + @destination_table = 'tempdb.dbo.monitoring_output' +``` + +```sql +Msg 213, Level 16, State 1, Line 1 +Column name or number of supplied values does not match table definition. +``` + +**How far you take this feature depends on how creative you are**. Some of you have come up with elaborate schemes, but I generally keep it simple. Something that I like to do is to set up a short semi-automated process by using Management Studio’s *GO [N]* option. I use this when I’m doing intense debugging, and will do something like: + +```sql +DECLARE @s VARCHAR(MAX) + +EXEC sp_WhoIsActive + @format_output = 0, + @return_schema = 1, + @schema = @s OUTPUT + +SET @s = REPLACE(@s, '', 'tempdb.dbo.quick_debug') + +EXEC(@s) +GO + +EXEC sp_WhoIsActive + @format_output = 0, + @destination_table = 'tempdb.dbo.quick_debug' + +WAITFOR DELAY '00:00:05' +GO 60 +``` + +This will first create a table in *tempdb*, after which it will collect the results every five seconds for a five-minute period. I set *@format_output* to **0** in order to get rid of the text formatting so that I can more easily work with the numeric data. **The results can be correlated to performance counters or other external information** using the [collection_time] column, which was added to Who is Active specifically to support automated data collection. + +------ +Prior: [The Output of Your Dreams](24_output.md) Next: [Delta Force](26_delta.md) +------ diff --git a/Docs/26_delta.md b/Docs/26_delta.md new file mode 100644 index 0000000..eee73bb --- /dev/null +++ b/Docs/26_delta.md @@ -0,0 +1,56 @@ +# sp_whoisactive: Delta Force + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Capturing the Output](25_capturing.md) Next: [Who is Active's Hidden Gems](27_gems.md) +------ + +The CPU is pegged. Your hard disks are fried. Memory consumption is through the roof. **Who is to blame?!?** + +Well that’s easy. Blame the session with the most CPU consumption. Blame the session doing the most I/O operations. Ask Who is Active what’s going on—it’ll tell you... + +![F26_01_cpu](image/F26_01_cpu.jpg) + +*Clearly* session 52 is the problem here. It’s consumed over 2,000,000 milliseconds of CPU time. Session 53, on the other hand, has consumed a paltry five seconds. No brainer, right? + +**Except that it’s not**. + +Session 52? It’s in a wait state. (WAITFOR, to be exact.) Not consuming any CPU time at all at the time I ran Who is Active. Session 53? Using plenty. So why the discrepancy? Does Who is Active have a major bug? + +The fact is—and this will be obvious to a lot of you, so forgive me—most of the metrics reported by Who is Active are *cumulative*. They’re totals from the entire session, or the entire lifetime of the request (depending on what’s going on). In the case of session 52 in the image above, that much CPU time was consumed over a five-minute period *prior* to the point in time when I ran Who is Active. Session 53, on the other hand, is *currently* consuming CPU time. But how do I figure that out? + +**The answer: delta mode.** This feature is something for which you can thank Jimmy May, who kept telling me about his “SQL Deltoids” script that he’d written back in the bad old days of SQL Server 2000. “If only there were a way to apply that script to the SQL Server 2005 DMVs,” he lamented one day. So I added the functionality into Who is Active. It’s quite simple, and surprisingly effective. + +To use delta mode, simply invoke Who is Active’s *@delta_interval* option. Setting an interval will cause the procedure to execute its main logic branch, then wait the specified amount of time—a number of seconds between 1 and 255—before running the same main logic branch again. All of the numeric values that changed during that period will be compared, and the changed numbers will be output in a series of columns named with *_delta* at the end. + +For example, here are the same two sessions as above, viewed in delta mode: + +```sql + EXEC sp_WhoIsActive + @delta_interval = 5 +``` + +![F26_02_delta](image/F26_02_delta.jpg) + +During the five-second delta interval, session 52 consumed no CPU time. Session 53, on the other hand, consumed over 5,000 milliseconds of time. If the CPU is pegged, 52 is no longer contributing—53 is the session of interest. + +Enabling delta mode will add some or all of the following columns to the output, depending on what other options have been set: + +- physical_io_delta +- reads_delta +- physical_reads_delta +- writes_delta +- tempdb_allocations_delta +- tempdb_current_delta +- CPU_delta +- context_switches_delta +- used_memory_delta + +By leveraging these delta columns in conjunction with the *@sort_order* option, it’s easy to quickly see which sessions are *currently* consuming your valuable server resources—which is generally more interesting than seeing which sessions may have been consuming resources but are now waiting or sleeping. + +Note: The various sessions and requests you'll see in delta mode pertain to the information captured after the wait interval. Information about requests that were running as of the first collection but are not running as of the second is discarded. New requests that started after the first collection will be shown, but with delta values of NULL. Locks, transactions, and other optional information, will also be captured only for the second collection, since no delta calculation is possible for those metrics (at least, not yet). + +------ +Prior: [Capturing the Output](25_capturing.md) Next: [Who is Active's Hidden Gems](27_gems.md) +------ diff --git a/Docs/27_gems.md b/Docs/27_gems.md new file mode 100644 index 0000000..629eb7e --- /dev/null +++ b/Docs/27_gems.md @@ -0,0 +1,37 @@ +# sp_whoisactive: Who is Active's Hidden Gems + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Delta Force](26_delta.md) Next: [Access for All!](28_access.md) +------ + +A few things that I’ve added to sp_whoisactive along the way have been especially useful, but there hasn’t been a good place to feature them in the articles. + +#### Always Show Blockers + +In [a prior article](09_deciding.md) I talked about filters. Filters let you decide exactly what you want to see, and what you not don’t want to see (“not” filters). But sometimes you have no choice: if you’re filtering so that you only see session 123, and it’s being blocked by session 456, you’ll also see information about session 456. The idea is that you should *always* get enough context to fully evaluate the problem at hand. Even if it means that you see more information than you were intending to see the first time around. You probably would have asked for 456 next anyway. + +#### “RUNNABLE” Waits + +In *@get_task_info = 2* mode, you may see waits called “RUNNABLE.” This could strike you as an oddity, given that *there is no such wait type* in SQL Server. I wanted to show [tasks on the runnable queue](13_queries.md), and making up a fake wait type seemed like a reasonable way of accomplishing the task. In practice, it has worked extremely well—I’ve used this feature countless times to help understand scheduler contention on a SQL Server instance. + +#### Accurate CPU Time Deltas + +CPU time is a tricky metric. It gets handled by Who is Active’s [delta mode](26_delta.md), and has for several versions. But historically, never very well. The data [simply isn’t represented in an easily-obtainable fashion](02_design.md) in the core DMVs. Recently I decided to dig deeper into this problem and discovered that I could get better numbers from some of the thread-specific DMVs. They’re cumulative numbers, based on the lifetime of the entire thread—not too good for the usual Who is Active output. But for snapshot and delta purposes, just about perfect. Meaning that in v11.00 of Who is Active, you can see the [CPU] column show a value of 0, while the [CPU_delta] column shows a value in the thousands. It’s not a bug. It’s a feature. (It really is!) + +#### Text Query Plans and the XML Demon + +SQL Server 2005 introduced query plans as XML. Management Studio knew how to render these plans graphically. And we were able to pull the plans from DMVs. Life was great. Except, perhaps, when you actually wanted to view one of these plans, and you had to save the thing out to a .SQLPLAN file, close the file, then re-open it. That’s about three steps too many for my taste, so I was overjoyed when the Management Studio team decided to wire things up the right way in SQL Server 2008. Click on a showplan XML document, see a graphical plan. Simple as that. + +Unfortunately, the XML data type has its own issues, including one particularly nasty arbitrary limitation that has to do with nesting depth. The idea is to make sure that XML indexes don’t crash and burn too often (not a big concern for me, given that I’ve never seen one used in a production environment—but I digress). The problem is that query plans are heavily nested. And to get that nice graphical plan workflow, SSMS needs the plan rendered as XML. + +In prior versions of Who is Active I gave up and returned either an error or a NULL. But in v11.00 I decided to make things a bit better. If the nesting issue occurs, Who is Active will now return the plan as XML encapsulated in some other XML in a text format, along with instructions on how to view the plan. This won’t give you a nice one-click experience, but it will give you the ability to use Who is Active to see some of the bigger plans that are causing performance issues. + +#### Service Broker Needs Love Too + +One of the most interesting features of Service Broker is activation. But a vexing design choice on behalf of the Service Broker team was to make activation procedures launch as system sessions. This means, among other things, that prior versions of Who is Active filtered them right out of the default view. To see them you’d have to enable *@show_system_spids*. And then you’d have to ignore all of the other system stuff. And you’d get woefully bad time information (no, the activation process hasn’t been running for 25 days; that’s the last time you restarted the SQL Server instance). In Who is Active v11.00 this has been fixed. Service Broker activation processes are now displayed by default along with other user activity. And I found a way to fix the timing issue, thanks to some advice on Twitter from Remus Rusanu, one of the guys who originally worked on Service Broker. So if you’re using activation and monitoring with Who is Active, life is good. + +------ +Prior: [Delta Force](26_delta.md) Next: [Access for All!](28_access.md) +------ diff --git a/Docs/28_access.md b/Docs/28_access.md new file mode 100644 index 0000000..b754119 --- /dev/null +++ b/Docs/28_access.md @@ -0,0 +1,75 @@ +# sp_whoisactive: Access for All! + +------ +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) [Documentation Index](ReadMe.md) +------ +Prior: [Who is Active's Hidden Gems](27_gems.md) +------ + +A prior article discussed [basic security requirements](04_installation.md) for Who is Active. I mentioned the VIEW SERVER STATE permission and the fact that I consider it to be “a relatively low barrier to entry.” + +But what if, in your organization, it’s not? **Auditing requirements being what they are, you might be required to lock things down**. And granting someone full and unrestricted VIEW SERVER STATE may simply not be an option. + +**Enter module signing**. By securing Who is Active (or any other securable, for that matter) via inherited permissions, it’s often possible to get around auditing requirements, as long as the module itself has been reviewed. This is not at all a difficult thing to do, but in my experience most DBAs haven’t played much with signed modules. Today I’ll show you how quick and easy it can be to set things up. + +#### Start by creating a certificate. + +```sql +USE master +GO + +CREATE CERTIFICATE WhoIsActive_Permissions +ENCRYPTION BY PASSWORD = '1bigHUGEpwd4WhoIsActive!' +WITH SUBJECT = 'Who is Active', +EXPIRY_DATE = '9999-12-31' +GO +``` + +Once you have a certificate in place, you can create a login from the certificate. The goal is to grant permissions, and to do that you need a principal with which to work; a certificate does not count. A login based on the certificate uses the certificate’s cryptographic thumbprint as its identifier. These logins are sometimes referred to as “loginless logins,” but [I refer to them as “proxy logins”](http://dataeducation.com/creating-proxies-in-sql-server/) since that’s what they’re used for: proxies for the sake of granting permissions. + +```sql +CREATE LOGIN WhoIsActive_Login +FROM CERTIFICATE WhoIsActive_Permissions +GO +``` + +The login can be granted any permission that can be granted to a normal login. For example, VIEW SERVER STATE: + +```sql +GRANT VIEW SERVER STATE +TO WhoIsActive_Login +GO +``` + +Once the permission has been granted, the certificate can be used to sign the module—in this case, Who is Active. When the procedure is executed, a check will be made to find associated signatures. The thumbprint of the certificates and/or keys used to sign the module will be checked for associated logins, and any permissions granted to the logins will be available within the scope of the module—meaning that the caller will temporarily gain access. + +```sql +ADD SIGNATURE TO sp_WhoIsActive +BY CERTIFICATE WhoIsActive_Permissions +WITH PASSWORD = '1bigHUGEpwd4WhoIsActive!' +GO +``` + +**Getting to this step will be enough to allow anyone with EXECUTE permission on Who is Active to exercise most of its functionality**. There are a couple of notes and caveats: First of all, every time you ALTER the procedure (such as when upgrading to a new version), the signature will be dropped and the procedure will have to be re-signed. You won’t have to create the certificate or the login again; you’ll just have to re-run that final statement. Second, you’ll only be able to use *most* of the functionality. Certain features, such as blocked object resolution mode, won’t operate properly, depending on whether the caller has access to the database in which the block is occurring. This may or may not be a problem—it depends on your environment and what users need to see—and Who is Active itself won’t throw an exception. An error message will be returned somewhere in the results, depending on what the user has tried to do. + +If you would like to grant database-level permissions based on the certificate login so as to avoid these errors, that’s doable to. Just do something like: + +```sql +USE AdventureWorks +GO + +CREATE USER WhoIsActive_User +FOR LOGIN WhoIsActive_Login +GO + +EXEC sp_addrolemember + 'db_datareader', + 'whoisactive_user' +GO +``` + +This will allow Who is Active to figure out what the various blocked or locked object names are. Since the login is just a proxy no one can actually log in and get direct access to read the data, so this isn’t something I consider to be a security risk. However, keep in mind that if anyone has the password for the certificate and sufficient privileges in *master*, a new module could be created and signed. Keep the password secure, and make sure to carefully audit to catch any infractions before they become a risk. + +------ +Prior: [Who is Active's Hidden Gems](27_gems.md) +------ diff --git a/Docs/ReadMe.md b/Docs/ReadMe.md new file mode 100644 index 0000000..ee65092 --- /dev/null +++ b/Docs/ReadMe.md @@ -0,0 +1,35 @@ +# sp_whoisactive Documentation + +[Home](https://github.com/amachanic/sp_whoisactive) [Download](https://github.com/amachanic/sp_whoisactive/archive/master.zip) +------ + +The sp_whoisactive documentation consists of the following articles. Please note that these articles were migrated from blog posts and are still being edited. Please excuse the occasional contextual oddity. + +1. [A Brief History of Activity Monitoring](01_background.md) +2. [Design Philosophy](02_design.md) +3. [The License](03_license.md) +4. [Installing sp_whoisactive](04_installation.md) +5. [Less Data is More Data](05_lessdata.md) +6. [Options](06_options.md) +7. [Default Columns](07_default.md) +8. [Active Request, Sleeping Session](08_requests.md) +9. [Deciding What (Not) To See](09_deciding.md) +10. [Commands, Batches, and the Mysteries of Text](10_commands.md) +11. ["Planning" for Success](11_planning.md) +12. [The Almighty Transaction](12_transaction.md) +13. [How Queries Are Processed](13_queries.md) +14. [Blocking, Blockers, and Other B Words](14_blockers.md) +15. [Seeing the Wait That Matters Most](15_waits.md) +16. [Seeing All of the Waits](16_morewaits.md) +17. [Is This Normal?](17_normal.md) +18. [Getting More Information](18_moreinfo.md) +19. [Why Am I Blocked?](19_whyblocked.md) +20. [The Node Knows](20_node.md) +21. [Analyzing Tempdb Contention](21_tempdb.md) +22. [The Key to Your Locks](22_locks.md) +23. [Leader of the Block](23_leader.md) +24. [The Output of Your Dreams](24_output.md) +25. [Capturing the Output](25_capturing.md) +26. [Delta Force](26_delta.md) +27. [Who is Active's Hidden Gems](27_gems.md) +28. [Access for All!](28_access.md) diff --git a/Docs/image/F10_01_default.jpg b/Docs/image/F10_01_default.jpg new file mode 100644 index 0000000..e703aec Binary files /dev/null and b/Docs/image/F10_01_default.jpg differ diff --git a/Docs/image/F10_01_full_text.jpg b/Docs/image/F10_01_full_text.jpg new file mode 100644 index 0000000..1308c3a Binary files /dev/null and b/Docs/image/F10_01_full_text.jpg differ diff --git a/Docs/image/F10_03_default.jpg b/Docs/image/F10_03_default.jpg new file mode 100644 index 0000000..663b845 Binary files /dev/null and b/Docs/image/F10_03_default.jpg differ diff --git a/Docs/image/F10_03_full_text.jpg b/Docs/image/F10_03_full_text.jpg new file mode 100644 index 0000000..528fbb0 Binary files /dev/null and b/Docs/image/F10_03_full_text.jpg differ diff --git a/Docs/image/F10_04_bad_paste.jpg b/Docs/image/F10_04_bad_paste.jpg new file mode 100644 index 0000000..bf2d1ff Binary files /dev/null and b/Docs/image/F10_04_bad_paste.jpg differ diff --git a/Docs/image/F10_04_xml.jpg b/Docs/image/F10_04_xml.jpg new file mode 100644 index 0000000..f2b0db1 Binary files /dev/null and b/Docs/image/F10_04_xml.jpg differ diff --git a/Docs/image/F10_05_outer1.jpg b/Docs/image/F10_05_outer1.jpg new file mode 100644 index 0000000..3bd0319 Binary files /dev/null and b/Docs/image/F10_05_outer1.jpg differ diff --git a/Docs/image/F10_05_outer2.jpg b/Docs/image/F10_05_outer2.jpg new file mode 100644 index 0000000..0ffdd71 Binary files /dev/null and b/Docs/image/F10_05_outer2.jpg differ diff --git a/Docs/image/F11_01_xml_plan.jpg b/Docs/image/F11_01_xml_plan.jpg new file mode 100644 index 0000000..c6b4a31 Binary files /dev/null and b/Docs/image/F11_01_xml_plan.jpg differ diff --git a/Docs/image/F11_02_full.jpg b/Docs/image/F11_02_full.jpg new file mode 100644 index 0000000..59fe207 Binary files /dev/null and b/Docs/image/F11_02_full.jpg differ diff --git a/Docs/image/F11_02_graphic.jpg b/Docs/image/F11_02_graphic.jpg new file mode 100644 index 0000000..4c237ff Binary files /dev/null and b/Docs/image/F11_02_graphic.jpg differ diff --git a/Docs/image/F11_02_xml.jpg b/Docs/image/F11_02_xml.jpg new file mode 100644 index 0000000..8fdc446 Binary files /dev/null and b/Docs/image/F11_02_xml.jpg differ diff --git a/Docs/image/F12_01_open_tran_count.jpg b/Docs/image/F12_01_open_tran_count.jpg new file mode 100644 index 0000000..54c5c6b Binary files /dev/null and b/Docs/image/F12_01_open_tran_count.jpg differ diff --git a/Docs/image/F12_02_start_time.jpg b/Docs/image/F12_02_start_time.jpg new file mode 100644 index 0000000..2e1a59e Binary files /dev/null and b/Docs/image/F12_02_start_time.jpg differ diff --git a/Docs/image/F12_02_two_dbs.jpg b/Docs/image/F12_02_two_dbs.jpg new file mode 100644 index 0000000..81ef76c Binary files /dev/null and b/Docs/image/F12_02_two_dbs.jpg differ diff --git a/Docs/image/F13_01_Restaurant.jpg b/Docs/image/F13_01_Restaurant.jpg new file mode 100644 index 0000000..fa313c1 Binary files /dev/null and b/Docs/image/F13_01_Restaurant.jpg differ diff --git a/Docs/image/F13_01_boring.jpg b/Docs/image/F13_01_boring.jpg new file mode 100644 index 0000000..30ad7cb Binary files /dev/null and b/Docs/image/F13_01_boring.jpg differ diff --git a/Docs/image/F13_02_cashier.jpg b/Docs/image/F13_02_cashier.jpg new file mode 100644 index 0000000..b2d4327 Binary files /dev/null and b/Docs/image/F13_02_cashier.jpg differ diff --git a/Docs/image/F13_03_HeatLamp.jpg b/Docs/image/F13_03_HeatLamp.jpg new file mode 100644 index 0000000..b920687 Binary files /dev/null and b/Docs/image/F13_03_HeatLamp.jpg differ diff --git a/Docs/image/F13_04_empty.jpg b/Docs/image/F13_04_empty.jpg new file mode 100644 index 0000000..58fac70 Binary files /dev/null and b/Docs/image/F13_04_empty.jpg differ diff --git a/Docs/image/F13_05_cooking_waiting.jpg b/Docs/image/F13_05_cooking_waiting.jpg new file mode 100644 index 0000000..d4e7c80 Binary files /dev/null and b/Docs/image/F13_05_cooking_waiting.jpg differ diff --git a/Docs/image/F13_06_cashier.jpg b/Docs/image/F13_06_cashier.jpg new file mode 100644 index 0000000..c9e4172 Binary files /dev/null and b/Docs/image/F13_06_cashier.jpg differ diff --git a/Docs/image/F13_07_yum.jpg b/Docs/image/F13_07_yum.jpg new file mode 100644 index 0000000..a587e0a Binary files /dev/null and b/Docs/image/F13_07_yum.jpg differ diff --git a/Docs/image/F14_53_blocker1.jpg b/Docs/image/F14_53_blocker1.jpg new file mode 100644 index 0000000..aa395ab Binary files /dev/null and b/Docs/image/F14_53_blocker1.jpg differ diff --git a/Docs/image/F14_53_more_info.jpg b/Docs/image/F14_53_more_info.jpg new file mode 100644 index 0000000..0fa8ba3 Binary files /dev/null and b/Docs/image/F14_53_more_info.jpg differ diff --git a/Docs/image/F14_53_not_blocker.jpg b/Docs/image/F14_53_not_blocker.jpg new file mode 100644 index 0000000..fca73b8 Binary files /dev/null and b/Docs/image/F14_53_not_blocker.jpg differ diff --git a/Docs/image/F14_53_requests_more_info.jpg b/Docs/image/F14_53_requests_more_info.jpg new file mode 100644 index 0000000..18af521 Binary files /dev/null and b/Docs/image/F14_53_requests_more_info.jpg differ diff --git a/Docs/image/F15_53_is_blocked.jpg b/Docs/image/F15_53_is_blocked.jpg new file mode 100644 index 0000000..f55fa9b Binary files /dev/null and b/Docs/image/F15_53_is_blocked.jpg differ diff --git a/Docs/image/F16_lots_of_info.jpg b/Docs/image/F16_lots_of_info.jpg new file mode 100644 index 0000000..26f55de Binary files /dev/null and b/Docs/image/F16_lots_of_info.jpg differ diff --git a/Docs/image/F16_task_info.jpg b/Docs/image/F16_task_info.jpg new file mode 100644 index 0000000..4c0d1ea Binary files /dev/null and b/Docs/image/F16_task_info.jpg differ diff --git a/Docs/image/F17_01_avg1.jpg b/Docs/image/F17_01_avg1.jpg new file mode 100644 index 0000000..49d9ade Binary files /dev/null and b/Docs/image/F17_01_avg1.jpg differ diff --git a/Docs/image/F19_01_blocked.jpg b/Docs/image/F19_01_blocked.jpg new file mode 100644 index 0000000..69ca995 Binary files /dev/null and b/Docs/image/F19_01_blocked.jpg differ diff --git a/Docs/image/F19_02_additional_info.jpg b/Docs/image/F19_02_additional_info.jpg new file mode 100644 index 0000000..68c1117 Binary files /dev/null and b/Docs/image/F19_02_additional_info.jpg differ diff --git a/Docs/image/F19_02_results.jpg b/Docs/image/F19_02_results.jpg new file mode 100644 index 0000000..2103d65 Binary files /dev/null and b/Docs/image/F19_02_results.jpg differ diff --git a/Docs/image/F1_01_sp_who2.jpg b/Docs/image/F1_01_sp_who2.jpg new file mode 100644 index 0000000..bce72a9 Binary files /dev/null and b/Docs/image/F1_01_sp_who2.jpg differ diff --git a/Docs/image/F1_01_sp_who2_thumb.jpg b/Docs/image/F1_01_sp_who2_thumb.jpg new file mode 100644 index 0000000..761d0a7 Binary files /dev/null and b/Docs/image/F1_01_sp_who2_thumb.jpg differ diff --git a/Docs/image/F1_02_Activity_Monitor.jpg b/Docs/image/F1_02_Activity_Monitor.jpg new file mode 100644 index 0000000..59e370e Binary files /dev/null and b/Docs/image/F1_02_Activity_Monitor.jpg differ diff --git a/Docs/image/F1_02_Activity_Monitor_thumb.jpg b/Docs/image/F1_02_Activity_Monitor_thumb.jpg new file mode 100644 index 0000000..d01ee17 Binary files /dev/null and b/Docs/image/F1_02_Activity_Monitor_thumb.jpg differ diff --git a/Docs/image/F20_01_CXPACKETs.jpg b/Docs/image/F20_01_CXPACKETs.jpg new file mode 100644 index 0000000..c5f3037 Binary files /dev/null and b/Docs/image/F20_01_CXPACKETs.jpg differ diff --git a/Docs/image/F20_02_node_id.jpg b/Docs/image/F20_02_node_id.jpg new file mode 100644 index 0000000..5e2ee6a Binary files /dev/null and b/Docs/image/F20_02_node_id.jpg differ diff --git a/Docs/image/F21_01_latch_waits.jpg b/Docs/image/F21_01_latch_waits.jpg new file mode 100644 index 0000000..26bb756 Binary files /dev/null and b/Docs/image/F21_01_latch_waits.jpg differ diff --git a/Docs/image/F21_01_tran_locks.jpg b/Docs/image/F21_01_tran_locks.jpg new file mode 100644 index 0000000..cd7ec0c Binary files /dev/null and b/Docs/image/F21_01_tran_locks.jpg differ diff --git a/Docs/image/F21_02_locks_database.jpg b/Docs/image/F21_02_locks_database.jpg new file mode 100644 index 0000000..f6b50a2 Binary files /dev/null and b/Docs/image/F21_02_locks_database.jpg differ diff --git a/Docs/image/F21_03_locks_object.jpg b/Docs/image/F21_03_locks_object.jpg new file mode 100644 index 0000000..b06db5d Binary files /dev/null and b/Docs/image/F21_03_locks_object.jpg differ diff --git a/Docs/image/F22_04_locks.jpg b/Docs/image/F22_04_locks.jpg new file mode 100644 index 0000000..5a8c245 Binary files /dev/null and b/Docs/image/F22_04_locks.jpg differ diff --git a/Docs/image/F23_01_blocked.jpg b/Docs/image/F23_01_blocked.jpg new file mode 100644 index 0000000..70328a8 Binary files /dev/null and b/Docs/image/F23_01_blocked.jpg differ diff --git a/Docs/image/F23_02_leaders.jpg b/Docs/image/F23_02_leaders.jpg new file mode 100644 index 0000000..9e18495 Binary files /dev/null and b/Docs/image/F23_02_leaders.jpg differ diff --git a/Docs/image/F24_01_column_list.jpg b/Docs/image/F24_01_column_list.jpg new file mode 100644 index 0000000..53719f4 Binary files /dev/null and b/Docs/image/F24_01_column_list.jpg differ diff --git a/Docs/image/F24_02_all_cols.jpg b/Docs/image/F24_02_all_cols.jpg new file mode 100644 index 0000000..55238ca Binary files /dev/null and b/Docs/image/F24_02_all_cols.jpg differ diff --git a/Docs/image/F24_03_right_justified.jpg b/Docs/image/F24_03_right_justified.jpg new file mode 100644 index 0000000..e71167a Binary files /dev/null and b/Docs/image/F24_03_right_justified.jpg differ diff --git a/Docs/image/F26_01_cpu.jpg b/Docs/image/F26_01_cpu.jpg new file mode 100644 index 0000000..cee126a Binary files /dev/null and b/Docs/image/F26_01_cpu.jpg differ diff --git a/Docs/image/F26_02_delta.jpg b/Docs/image/F26_02_delta.jpg new file mode 100644 index 0000000..a968c06 Binary files /dev/null and b/Docs/image/F26_02_delta.jpg differ diff --git a/Docs/image/F2_01_WIA.jpg b/Docs/image/F2_01_WIA.jpg new file mode 100644 index 0000000..84d9779 Binary files /dev/null and b/Docs/image/F2_01_WIA.jpg differ diff --git a/Docs/image/F5_01_blank.jpg b/Docs/image/F5_01_blank.jpg new file mode 100644 index 0000000..899c744 Binary files /dev/null and b/Docs/image/F5_01_blank.jpg differ diff --git a/Docs/image/F5_02_nonblank.jpg b/Docs/image/F5_02_nonblank.jpg new file mode 100644 index 0000000..306ff93 Binary files /dev/null and b/Docs/image/F5_02_nonblank.jpg differ diff --git a/Docs/image/F6_01_help.jpg b/Docs/image/F6_01_help.jpg new file mode 100644 index 0000000..8041b8e Binary files /dev/null and b/Docs/image/F6_01_help.jpg differ diff --git a/Docs/image/F7_01_active_sleeping.jpg b/Docs/image/F7_01_active_sleeping.jpg new file mode 100644 index 0000000..86e76fb Binary files /dev/null and b/Docs/image/F7_01_active_sleeping.jpg differ diff --git a/Docs/image/F7_02_disconnected.jpg b/Docs/image/F7_02_disconnected.jpg new file mode 100644 index 0000000..a2a591c Binary files /dev/null and b/Docs/image/F7_02_disconnected.jpg differ diff --git a/Docs/image/F8_just_adam.jpg b/Docs/image/F8_just_adam.jpg new file mode 100644 index 0000000..c10b82d Binary files /dev/null and b/Docs/image/F8_just_adam.jpg differ diff --git a/Docs/image/F8_just_adam_thumb.jpg b/Docs/image/F8_just_adam_thumb.jpg new file mode 100644 index 0000000..063d061 Binary files /dev/null and b/Docs/image/F8_just_adam_thumb.jpg differ diff --git a/Docs/image/F8_lots_of_activity.jpg b/Docs/image/F8_lots_of_activity.jpg new file mode 100644 index 0000000..a5d61a0 Binary files /dev/null and b/Docs/image/F8_lots_of_activity.jpg differ diff --git a/Docs/image/F8_lots_of_activity_thumb.jpg b/Docs/image/F8_lots_of_activity_thumb.jpg new file mode 100644 index 0000000..edd1ac8 Binary files /dev/null and b/Docs/image/F8_lots_of_activity_thumb.jpg differ diff --git a/README.md b/README.md index 13ce588..0515fe5 100644 --- a/README.md +++ b/README.md @@ -10,7 +10,9 @@ The license is now [GPLv3](/LICENSE). -Documentation is still available at http://whoisactive.com/docs +[GitHub Documentation](/Docs/ReadMe.md) + +Documentation is also available at http://whoisactive.com/docs If you have enhancements, please consider a PR instead of a fork. I would like to continue to maintain this project for the community.