Tag Archives: database

Conditional branching and OPTION(Recompile)

Conditional branching, OPTION(Recompile) and procedure plan


Summary

There are many cases when programmers use conditional branching in tsql code to execute different queries or similar queries with different predicates based on a certain condition. In this post I’ll try to explain how Query optimiser handle queries in different conditional branches and how it relates to the option(recompile) hint and the procedure plan.

Conditional branching in stored procedures

Our Tsql code may implement logic which use conditional branching to decide what business rule to apply. Take for example a simple, non-production process that selects the order details associated with a productId. If the product is not included in any of the  sales Orders, return nothing – or a warning message.

Create test data

The script below creates a sample table with the following ProductId data distribution.


Figure 1, ProductId data distribution 

The figure above reads as follows i.e
ProductId = 0 participates in 100 Orders. The number of orders makes 0.1% of all orders. The same applies for ProductId 100,200,300 …4900, or 50 different ProductIds.
ProductId=40000 participates in 10,000 orders. The number of orders makes 20% of all orders. The same applies for ProductId 60000 and 80000, or 3 different ProductIds.

The script used to check data distribution …

Test stored procedure

Experiment 1
Proc. plan is generated for all branch paths

The first experiment shows that QO (query optimser) builds query plans for all code branches regardless of which one is executed on the very first sproc call. This is expected since procedure plan( a set of query execution plans) is generated and cached without knowing which code path will be chosen.

Execute stored proc without passing @ProductID parameter value. The parameter is an optional param and will have default value NULL.

Notes:
GO 100 is to ensure that the plan stays in memory for some time. This is not needed for server level environments.
The 2nd query selects the procedure’s cashed plan(this is a set of estimated plans – no run-time values 🙂 ). In this example, the complete proc plan has two main query plans branched from T-SQL(COND WITH QUERY) operator.


Figure 2, Proc plan contains query plans for all code branches

The cached procedure plan shows that the second branch query plan is optimised by using the same parameter value (ProductId = NULL).

Note: The estimated number of rows is 1. Because the initial, NULL value is not represented by a RANGE_HI_KEY, Sql Server will use AVG_RANGE_ROWS value (stats histogram) instead. If we used i.e ProductId =2008 instead of NULL, the estimated number of rows would be 100 – use DBCC SHOW_STATISTICS('dbo.TestBranchPlans' ,'NCI_ProductId') to observe this behavior. 

The stored procedure call did not return any rows and the execution plan was built for @ProductionId = NULL. All subsequent calls may have sub-optimal plans as presented below.

FIgure 2, Plan stability problem (Parameter sniffing problem)

*Accuracy[%] = (No of Actual Rows /  No. Of estimated rows ) * 100
This feature is available in SSMS 18.x+

Accurracy = 100%  – Ideal case, The estimated number of rows was spot on
Accurracy <100% – Overestimate. The estimated number of rows is higher than the actual no. of rows
Accurracy >100% – Underestimate . The estimated number of rows is lower than the actual number of rows.

Figure 2 shows negative effect of the cached, sub-optimal procedure plan, on the subsequent procedure calls.

Unstable procedure plan

Previous experiment showed how Sql Server builds query plans for all code paths without knowing which one will be executed. Query optimiser use the value passed into @ProductID parameter to create query plans for all queries in the batch that references it. In the test we called stored procedure without passing @ProductId, The absence of the value instructed the code to use parameter’s optional value, @ParameterId = NULL. As a consequence, QO used an atypical value to build and cache a sub-optimal query plan, which then had a negative impact on all subsequent procedure calls.
But the effect could be the same even if we passed any value to @ProductId.
Figure1 shows that the values in ProductId column are not evenly distributed (which is usually true for the production systems 🙂 ). However, most of the ProductIds, 76% (50 out of 66 different ProductIds) returns the same number of rows(100 rows). There is 15% ProductIds (10 out of 66) that returns 500rows and only 3% ProductIds (3 out of 66) that returns 10,000 and 20,000 rows.

Lets say that our procedure call pattern assumes similar probability of passing “small”, more selective*(returns only 100 rows)  and “big”, less selective(returns 20,000 rows) ProductId values.

*Selectivity represents uniqueness of values in a column. High selectivity = high uniqueness = low number of matching values. Selectivity = (rows that pass the predicate / total rows in the table). Selectivity[ProductId=200] = 100 / 100,000 =0.001(high selectivity)  and [ProductId = 40000] = 20000/100000 = 0.2 (low selectivity)

A cached procedure plan compiled for a “small” ProductId has a negative impact on the procedure executions with a “big” ProductId and vice versa.


Figure 3, Cached plan for a small ProductId

We would get the similar results if we passed a “big” ProductId first, and then made a procedure call passing a “small” value to the parameter, only this time the cached procedure plan would work in a favor of the “big” parameter.
This situation is known as “parameter sniffing” problem. The result is an unstable procedure plan.
One of a several different ways to resolve the problem is to instruct query processor to recompile the statement in question, on every procedure execution.

OPTION(RECOMPILE)

OPTION(RECOMPILE) is a statement level command that instructs query processor to pause batch execution, discard any stored query plans for the query, build a new plan, only now using the run-time values (parameters, local variables..), perform “constant folding” with passed in parameters.

Experiment 2
Conditional branching and OPTION(RECOMPILE)

In this experiment I’ll use OPTION(RECOMPILE) to stabilise the procedure plan. Lets repeat the last test, but this time we instruct query processor to recompile statement in question


Figure 4, Stable procedure plan with Option(Recompile)

Note: Using OPTION(recompile) to stabilise the plan comes with a certain cost. It adds a small overhead to the query compile time, can have some impact on CPU. It is a good idea, if possible, to re-write/decouple stored proc in order to prevent high variations in the procedure plans.
Personally, I’ve witnessed great results with the option(recompile) in the frequently executed stored procedures with the plan stability problem.

Where is my procedure plan?

In the next test we’ll run our stored procedure with the option(recompile), with a parameter value that does not match any existing ProductId value. This call will execute the first code branch and exit the batch.


Figure 5, Incomplete procedure plan 

So, now we need to answer question “why we are not getting our cached procedure plan (cached_plan is NULL)”.    🙂

Deferred Query compilation

When a client app executes stored procedure for the first time, query processor may decide not to create query plans for each individual query. This behavior is called Deferred Query Compilation. Some of the possible reasons are related to the conditional branching.
If the first call does not execute a code branch that contains at least one option(recompile) statement – there may be more than one statement in a code branch, the query plans for the branch will not be generated and cached. This makes procedure plan, as a set of individual query plans, incomplete.
Dynamic management function sys.dm_exec_query_plan(plan_handle) returns all individual query plans for the entire batch. If one or more query plans are not generated, the function returns NULL. This makes sense since we do not have complete procedure plan.
The following test demonstrate this behavior.

1. Create a new test stored proc dbo.TestCodeBranching1

2. Run the script below.

Results
Figure 6, Individual query plans

The sequence of events as follows:

  • The first branch got executed during the very first stored procedure call.
  • Query processor finds an Option(recompile) statement within  the second code branch and decides not to create execution plans for any of the queries in the code path.
  • Dynamic management fn, sys.dm_exec_query_plan(plan_handle) did not return cached procedure plan because the plan was incomplete.
  • Dynamic management function sys.dm_exec_text_query_plan(plan_handle, statement_start_offset, statement_end_offset) returned all available single query plans within the batch. In our case we have only one cached query plan. The plan belongs to the code path that was executed on the first call.

How the sys.dm_exec_text_query_plan query works?

The query collects data from the following objects:
sys.dm_exec_query_stats – gets various statistical information for cached query plans. We use sql_handle column (uniquely identifies the batch or stored procedure that the query is part of), plan_handle (uniquely identifies query execution plan for the queries that belongs to the batch), statement_start_offset, statement_end_offset ( define, in bytes, the starting and and ending position of a query within batch)
sys.dm_exec_sql_text – gets the text of the batch of the queries identified by sql_handle.  It also provides info about proc name, database etc..
-sys.dm_exec_text_query_plan  – returns execution plan for a batch of statements or for specific statement(s) in the batch. statement_start_offset(0 beginning of the batch) and statement_end_offset (-1 end of the batch) define the start and end position of the query within the batch defined by plan_handle.

Conclusion

Conditional branching as an imperative construct in TSQL has a specific treatment by Sql Server’s query processor. A procedure batch with conditional branching may be optimised and cached for all code paths regardless of which branch is executed on the first procedure call. This may produce sub-optimal plans for a number of queries within the non-executed code branches. It is important to be aware of the behavior in order to prevent potential sub-optimal query executions.
Sql Server may choose not to compile statements(deferred query compilation) within the non-executed code paths if at least one of the queries within the code paths has the OPTION(recompile) hint – this is also true for temp tables. This will make the procedure plan (as a set of query plans)  incomplete, hence sys.dm_exec_query_plan function returns NULL for the plan handle. However, queries from the executed code branch will be cached and the query plans will be available through sys.dm_exec_text_query_plan.

Thanks for reading.

Dean Mincic

Data providers and User Options

Data providers and User Options


Summary

Some time ago I decided to write a quick post about ANSI_WARNINGS, one of Sql Server’s user options. Half way through, I discovered many interesting things around the mechanisms that sets Client connection/session user settings. That was definitely more fun to research and blog about 🙂
Sql Server configuration settings include several settings called User options.  Those options, along with some other settings define the user connections environment related to query processing. The options define i.e how queries handle the 3VL(Three Valued Logic – ANSI_NULLS) or how they enforce atomicity of the explicit transactions (XACT_ABORT) etc.
There are a few levels where the options can be set: Server, Database and session levels. The values can also be independently  set by Sql Server engine and the data providers after the successfully established Client connection. Different Db tools like SSMS may have their own settings on top of the previously mentioned. This blog aims to shed some light on the processes that change the connection/session user option settings.

SQL Server Configuration Settings overview

Sql Server’s configuration settings can be set on three different levels.

  1. Server configuration settings
  2. Database configuration settings
    2.1 Connection settings set by Sql Server/ Data providers during the Database Login process/after the successfully established Client connection.
  3. SQL Server session(connection) configuration settings (SET statements on a session level)

For the most of the settings, the values can be set on more than one level. The overlap introduces the precedence of the values set on the lower levels over those set on the higher levels i.e QUOTED_IDENTIFIER setting value defined on the session level (3) overrides the same setting value on the database(2) and/or Server level(1).
Sometimes, the concept may be confusing and this is only my personal feel, since there is a number of different ways to assign values to the same settings and on a few different levels.

Some of the settings can only be set on certain levels. i.e  Max workers treads (configures the number of worker threads that are available to SQL Server processes) can be set only on the server(instance) level, and AUTO_CREATE_STATISTICS( If not already available, Query Optimizer creates statistics on individual columns used in a predicate) can only be set on database level*.

NOTE: All database settings are inherited from the model db during the database creation.

As mentioned, this post will be focusing only on a sub-set of the server settings, the User Options settings.

User Options

Figure 1 below shows the categories of the user options and their values. The bit settings are presented as decimal numbers – this will be explained later in the blog.


Figure 1, User Options

User Options can be set up on three different levels; Server, Database and Session level.

Server level

Server level defines User Option settings for all Client connections. User options on this level can be managed in a few different ways.

  • sys.sp_configure , system stored procedure


Figure 2, Default User Option(s)

The system stored procedure manages server configuration settings.
@configname is an option name or, in our case  the name of a group of options.  config_value is a combination of values presented in Figure 1.  The default config_value is 0 representing the default state of user settings – all set to OFF.

More about config_value

The config_value is a small, positive integer. This means that the maximum value that can be used is 32768 – 1 = 32767   or 215 – 1.  One  bit is used for the  integer sign.

The config_value is also a 2 bytes(16 bits) bitmap used to store the user setting values. The first 15bits are used to store the values (although the 1st – DISABLE_DEF_CNST_CHK has been discontinued since Sql Server 2012).

Lets say we want to turn ON the following user settings

ANSI_WARNINGS  (decimal value 8)
ARITHABORT (decimal value 64) and
CONCAT_NULL_YIELDS_NULL (decimal value 4096)

Figure 3 is a graphical representation of the 2byte bitmap and the corresponding binary and  decimal values. The last bit (binary 215 ,decimal 32768) is not in use.

Figure 3, User Options – config_value

To turn ON the corresponding bits, we just add decimal values like :  8 + 64 +4096 = 4168 (or using bitwise OR) i.e SELECT (8 | 64 | 4096)  We then pass the value to the  configvalue parameter of the sys.sp_configure system stored procedure.

This means that the all subsequent client connections may have the settings turned ON. More on this in the following sections.

  • SSMS GUI, Server Settings/Properties/Connections

Another way to manage User Options on the server level is by using SSMS tool. Figure 4 shows the user_options accessed through the UI.


Figure 4, User Options – SSMS

The default state of the user option values on the Server level  is all OFF.

Database level

Similar to the Server level user options, database level user options define the user option values for all the Clients that will be connecting to the particular database. The database settings are supposed to override the same settings that were set on a higher, server level.
Database level user options as well as server level user options are, by default all set to OFF.
NOTE: The Database level user options becomes more interesting in the context of Contained Sql server(2012+) databases or its Cloud counterpart , the Azure SQL Database

To change user options on the database level use ALTER DATABASE statement.

To check the current user option values we can use system functions or system views.

Figure 5 shows a sub-set of the User Options available on the database level.

Database user options settings
Figure 5, Database level user options

The following user options are available on the server level but not on the database level.
– ARITHIGNORE
– NOCOUNT
– XACT_ABORT
– IMPLICIT_TRANSACTIONS

ANSI NULL Default (ANSI_NULL_DEFAULT) represents the Server level  ANSI_NULL_DFLT_ON and ANSI_NULL_DFLT_OFF.

By default, server level user option settings should be overwritten by the corresponding database level settings. However,  for most of the options this is not true. Data providers responsible for establishing connections between client applications and database will override the settings defined on both levels.

Connection settings set by Sql Server/ Data provider

I was not able to find many white papers that covers Sql Server Data providers’ role in configuring user options. The following conclusions are based on my personal research and experiments.

For a start, let’s set up a simple Ext. Event session that reports on the  following events;

  • Login event. The main Event field of interest will be the option_text field.
  •  sql_batch_starting and sql_batch_completed – sql_text field
  •  sql_statement_starting and sql_statement_completed – sql_text field

The last two events will be used in the subsequent experiments.


Figure 6, Login event

Now, let’s connect to a test database using a simple powershell script and observe the Login event attributes


Figure 7, options_text field value

By analysing the output we can observe a couple of interesting things.

  • The Server/Database user settings have been overwritten by the new values i.e ANSI_PADDING is originally set to OFF on both levels and then turned ON during the SqlConnection.Open() process.
  • Some other connection settings are set i.e dateformat, transaction isolation level ..etc

In addition, I compared the user option values set by different  data providers;

  • .NET Framework Data Provider for Sql Server/ODBC/OLEDB (pshell script)
  •  ODBC v3 and v7 (Python and sqlCmd)
  •  Microsoft JDBC Driver 7.0 for SQL Server (java app)

The results were always exactly the same – the identical set of user option values.

Now, the question I was trying to answer was ; What was the process that set the values presented in the Figure 7? The option_text event field  description says:
“Occurs when a successful connection is made to the Server. This event is fired for new connection or when connections are reused from a connection pool”
This may suggest that Data Providers may be responsible for setting the option values and at some stage during the login process.
To  further investigate this, I have ran a powershell script similar to the one used in the previous test. This time I used ODBC Data Source Administrator (for 32bit env) to trace the ODBC communication(function calls) between the Client app and Sql Server.


Figure 8, ODBC Administrator – Trace ODBC function calls

The trace did not show any ODBC function calls that set up the user options captured by the Login event. It was “nice and clean” log.
In the next experiment, I used a simple sqlcmd.exe script to connect to the same database. Sqlcmd utility uses (at least ver. 14.0.1 I have on my laptop) ODBC Driver 13 for Sql Server. This is visible in the ODBC trace file – Figure 10.

Again, no “interesting” function calls during the login phase. However,  there were two function (SQLSetStmtAttrW) calls that took place after the successfully established connection.

Figure 9, Post Login events

Figure 10, ODBC Trace snapshot  – SQLSetStmtAttrW() function

The log shows that there were two sets of changes on the user options  initiated by data providers;

1. Pre-login/During the login process (captured by the Login event)
2. Post-login changes (captured by sql_batch/sql_statement events)

Post-login changes

In this experiment I’ve tried to consolidate and document the post login user options values set by different providers. The idea is to execute a simple program using different data providers, that will:

  1. connect to the test database
  2. execute a view that selects the user option values for the current session.
  3. output the results of the view
    i. e C:\Users>sqlcmd -S tcp:(local) -d TestDB -q "select * from dbo.vwGetSessionSETOptions"

The view definition:

The output shows the user options that would be applied on any batch/stored proc, function, ad-hoc query if executed within the active connection (or the @@spid session from SQL Server’s perspective). The partitioned view includes the data provider’s details available through sys.dm_exec_sessions dynamic management view.

Figure 11, Post-login user options values

From the result (the figure above may be an overkill 🙂 ) we can conclude that data providers can change some of the user settings and that can produce unexpected results. Consider the scenarios below;

  • If we execute a Python script that i.e inserts a some rows into a table..

.. the INSERT will NOT happen since the data provider had set the IMPLICIT_TRANSACTIONS to ON. To see how SQL Server implements the post-login change, run the script along with the Extended Event Session – Figure 9.

  • If we execute an sqlCmd query to i.e insert some values in a table that has a filtered index, we’ll get the following error.

Msg 1934, Level 16, State 1, Server ENETT-NB290, Line 1 INSERT failed because the following SET options have incorrect settings: ‘QUOTED_IDENTIFIER’. Verify that SET options are correct for use with indexed views and/or indexes on computed columns and/or filtered indexes and/or query notifications and/or XML data type methods and/or spatial index operations.

Other data providers may change settings like;  dbLib  data provider sets ANSI_WARNINGS user option value to OFF. This may cause the logical errors that may be difficult to debug.

SSMS post login changes

SSMS application performs its own set of post-login changes. The changes can be managed through the application UI on two levels;

  • Current session level(query editor) – The changes affects only the current session.
    • Right Click on the query editor area/ Query Options/Execution – ANSI
  • Application level where the changes affects all sessions.
    • Tools/Options/Query Execution/ SQL Server/ANSI

Developers, should be aware of the fact that the same query executed from SSMS and a Client application may behave differently and produce different results. i.e The INSERT query executed through the Python script above would commit changes if executed in SSMS.

Pre-login changes

As mentioned before – Figure 7, there are nine User settings set by Data providers (or Sql Server engine) during the login process. In the next experiment I’ll try to show how the nine Server level settings get affected/overridden by the pre-login changes – loosely speaking 🙂

Initially, all server level user settings are turned OFF – Figure 2  and that includes the 9 options mentioned before.
Let’s see what happens on the session level if we set ALL Server level user options to ON. For the experiment I’ll use a PowerShell script similar to the one used before, to  connect to Sql Server.

Before executing the script, lets change server level user settings and check the effects of the changes through SSMS GUI, Figure 4.

NOTE: Some of the user settings are mutually exclusive.

  • ANSI_NULL_DFLT_ON and ANSI_NULL_DFLT_OFF
  • ARITHABORT and ARITHIGNORE

The figure below shows the session level user options settings output for the two Server level user options settings scenarios. The snapshot combines two outputs.

FIgure 12, Session level user settings 

As we can see, the user options business is pretty unclear and confusing. Combining findings from the previous experiments, I compiled a table that may explain the sequence in which the user options are set, but before that, just another thing to mention – the ANSI_DEFAULTS setting. The setting controls(sets to ON) a group of user options values. This is to provide the ANSI standard behavior for the options below;

  • ANSI NULLS
  • ANSI_PADDING
  • ANSI_WARNINGS
  • QUOTED_IDENTIFIER
  • ANSI_NULL_DFLT_ON
  • CURSOR_CLOSE_ON_COMMIT
  • IMPLICIT_TRANSACTIONS

The status of the ANSI_DEFAULTS can be checked using the query below.

When checked, status is usually 0 (not set) because some of the user settings from the list gets overridden by the pre-login/post login processes mentioned before.

Figure 13, User Option settings sequence

During application login attempt, data provider/Sql server engine turns ON a set of user options grouped in the ANSI_DEFAULT settings. This overrides the user options set on server level(Phase 1). Right after the change, another set of changes overrides a couple of ANSI_DEFAULTS options and a few server level user options(Phase 2). At this stage the login process is finished and  9 out of 15 option values is reported by the login xEvent(option_text field).The color of user options at the final session level shows the levels from which the values ​​came from.

*The ARITHABORT and ARITHIGNORE shows a different behavior.

  • The options are mutually exclusive if set on server level (only one setting can be set to ON.
  • If one of the settings is set on server level the setting will not be changed through the login process.
  • If none of the settings is set on server level, ARITHABORT will be set to ON during the Phase 2.
  • Only ARITHABORT value will be reported by the login_xevent.

Data providers like ODBC, dbLib perform additional changes to the user options after successfully establishing a database connection.

Session level setting

Once connected, Client code can override previously set user options  by using SET statements directly in the code. This would be the final override of the user option values 🙂 . The scope of the settings will be the current session( or from the Client’s perspective, the current connection). The following coder shows a few user options set in a stored procedure’s header…

Conclusion

The User Options are a set of configurable elements that affect query behavior i.e handling 3VL(three valued logic), division by zero situations,  data truncation rules etc. As Sql developers we need to be aware of the environment in which our queries are being executed. There are many different levels where user options can be set; Server, Database and session levels. Session level has precedence over the other two levels. However, Sql server can set up its own default user option values during and after the login phase – when a client application makes an attempt to connect to Sql Server. Data providers can also independently change user option settings, during and after the login process. The impact of the changes can introduce logical errors such as e.g always rolled back inserts/updates/deletes ( implicit transaction set to on) or code execution errors such as insert failures on a table with a filtered index. There are scenarios when user options settings can cause the sneaky logical errors that are very difficult to debug e.g.  what if NULL = NULL suddenly evaluates to true(ansi nulls off).
The session level can provide a place where we can set user option values which will override all previously set options. Designing templates for Sql Server objects (stored procedures, functions..etc) that will include the option settings in the header may be a good way to put the whole user option confusion to the rest 🙂

Thanks for reading.

Dean Mincic

 

 

Statistics used in the cached execution plans

Statistics used in the cached execution plans – Stored Procedures


Summary

Query optimisation process sometimes requires understanding on how Sql Server’s Query engine compiles, re-compiles and executes sql batches. Some of the most important elements used by Query optimiser when constructing a good plan are the “Interesting statistics”. These are statistical information used by Query optimiser  when constructing a good enough query execution plan.
This blog attempts to explain what are the “interesting statistics”, when they are updated and how the statistical information relates to the query recompilation process. The topic is related to Temporary tables statistics when used in stored procedures.

Batch compilation and recompilation

To begin with, let’s analyse the batch compilation/recompilation diagram (By Arun Marathe, Jul 2004, Batch Compilation, Recompilation and Plan Caching Issues in Sql Server 2005). The idea is to create a set of  experiments that will capture the behavior of a stored procedure  through the different phases of the query compilation/recompilation process, particularly those related to the statistics that are used to generate the execution plan.


Figure 1, Batch Compilation/Recompilation diagram

I’ve used AdwentureWorks database to set up the test environment and MS Profiler to capture various Events relevant for the experiments.

MS Profiler events

    1. Attention (Errors and Warnings)
    2. Auto Stats (Performance)
    3. SP:CacheHit (Stored Procedures)
    4. SP:CacheInsert  (Stored Procedures)
    5. SP:CacheMiss  (Stored Procedures)
    6. SP:CacheRemove  (Stored Procedures)
    7. SP:Completed  (Stored Procedures)
    8. SP:Recompile  (Stored Procedures)
    9. SP:Starting  (Stored Procedures)
    10. RPC: Starting (Stored Procedures)*
    11. RPC:Completed (Stored Procedures)*
    12. SP:StmtStarting  (Stored Procedures)
  1. SQL:StmtRecompile (TSQL)
  2. SQL:StmtStarting  (TSQL)

Database Objects
Set AdventureWorks DB compatibility level to 140 – Sql Server 2017. The version provides easy access to the information about the interesting statistics saved with the query plan (SSMS – SELECT Plan Operator, Properties,OptimizerStatsUsage).

Below is the set of Sql Server object definitions used for the testing.

Information about the statistics/indexes on the tables can be retrieved using the queries below.

The following examples assume the default settings for the Sql  Server’s options related to the statistics:
 AUTO_CREATE_STATISTICS ON
– AUTO_UPDATE_STATISTICS ON
AUTO_UPDATE_STATISTICS_ASYNC OFF 

A bit of theory first before proceeding with the tests. : )

colmodctr

colmodctr is an ever increasing counter that tracks the changes made on tables (a counter per column excluding the non-persistent computed columns). colmodctr is not transactionally consistent which means that is not affected by the rolled back changes i.e if a transaction inserts 10 rows in a table and then roll-back, the counter will still report 10 changes.
Sql Server Statistics (automatically/manually created/updated) on a column(s) will store the snapshot value of the colmodctr for the leftmost column in the stats-blob.
The counter is a very important since it’s one of the elements that drives the query recompilation decisions related to the statistics changed reasons. 

colmodctr counter can be accessed through the following system views.


Figure 2, colmodctr, system views – standard and hidden

One way  to access the hidden tables is to; Open a separate SSMS instance, close the object explorer, create a single connection using Server name: i.e ADMIN:(local)
NOTE: The structure of the hidden tables and the tables’ accessibility is not documented and may be changed in the future versions.

Recompile thresholds (RT)

RT concept defines the number of changes on a table column needed to be done in order to indicate the statistical information of that column as stale. 
The changes includes the column values changes through the DML operations such as INSERT, UPDATE, DELETE… i.e Inserting 10 new rows in a table is considered as 10 changes(identified by the colmodctr counters mentioned before).
If the table does not have statistical information i. e HEAP table with no indexes and no manually created statistics, and the query plans that references the table does not load/automatically create interesting statistics, the only relevant change when performing the RT crossing test will be the change in the number of rows inserted and/or deleted.

colmodctr(current) – colmodctr(snapshot) |  >= RT

or

 | cardinality(current) – cardinality(snapshot) |  >= RT

current     – refers to the current value of the modification counter
snapshot – refers to the value of the mod. counter captured during the last plan compilation(recopilation).
cardinality* – the number of rows in the table.

*cardinality has different meaning in the different contexts: Cardinality may represent the uniqueness of data values in a particular column – the lower the cardinality the more duplicated values in the column.
Cardinality is also a way to define the relationship between two entities in a data model. It is also known as the degree of relationship i 1-1, 1-m, m-n.

The Threshold Crossing  Test evaluates to TRUE if the number of changes is greater than the predefined RT value (see Figure 3)

Recompilation thresholds(RT) for all the tables referenced in the query are stored along with the query plan.

RT depends on the table type(permanent vs temporary) and the number of rows in the table.


Figure 3, Recompile thresholds

Special case. RT = 1 if the table has 0 rows (with or without statistics)

NOTE: Starting from SQL Server 2008 R2 SP1, Microsoft introduced TF2371. The trace flag activates the dynamic recompile threshold calculation. The higher number of rows in a table, the lower the RT. The functionality is implemented to allow automatic statistics updates to kick off more frequently for the big tables. i.e RT for a 10,000 row table is 500 + 0.20*10,000 = 2,500 – the number of changes required to trigger query recompile. For a table with 100M rows, the RT is 20,000,500. For some applications the RT may be too high, resulting in the sub-optimal plans due to the lack of query recompilation. Hence the TF2371.
Starting from SQL Server 2016, the TF2371 is turned on by default.

Here is a couple of examples to illustrate Figure3.
If there is a table A that contains 230 rows, RT for the table will be set to 500. This means that if we i.e insert 500 rows, the total number of rows (c)  will change to 730 (c>=230+500) which is enough changes to make the table’s statistics stale.
The change itself does not mean much if there are no queries that references the table : )
The query plans may or may not initiate the auto-statistics creation on the specific table columns. Also, the referenced tables may not have any statistical information i.e HEAP table with no non-clustered indexes.

Experiments

Experiment 1 (stats change before query execution)

In this experiment we will make “enough” changes to the ListPrice column (dbo.Products table) BEFORE running the stored procedure for the first time, 
The column is a key column in NCI_Products_ListPrice, the non-clustered index and has statistical information attached to it (the stats object name is the same as the NCI)

Lets begin the experiment by creating the test objects and checking the statistical information on the tables.

Step 1, Check the initial stats/rowmodctr information

Figure 4, Initial rowmodctr information

Step 2, Check stats BLOB and make changes on dbo.Products table

Run the DBCC  command below before and after the UPDATE to confirm that there were no changes in the stats BLOB information.

NOTE: rowmodctr is not transactionally consistent.

Figure 5, stats BLOB information

Figure 6, rowmodctr after the initial dbo.Products update

The changes are detected and available through Sql Server’s metadata.

Step 3, Run the stored procedure and observe the captured events by the Profiler.

Figure 7, Statistics refresh

Following the batch compilation diagram we can identify the following steps.

  1. Cache Lookup step resulted in the SP:CasheMiss event. dbo.TestQueryExecution stored proc. does not exist in the cache.
  2. Query Compilation Begins. SQL Server engine is about to load all of the  “interesting statistics”. The loaded statistics can be retrieved from the Actual Execution Plan, the SELECT physical  operator – OptimiserStatsUsage property.
  3. Query engine checks if any of the loaded  interesting statistics are stale. If yes, the system stops the batch compilation process and refreshes the statistics. In our case the system has 
    • Identified the number of changes made on the ListPrice column. From the stats/index information gathered after the initial update, the number of changes (rowmodctr/Modifications) is 610
    • Performed RT crossing test.  The test passed since the number of changes(610) exceeded the RT for tables with the number of rows greater than 500. RT = 500 + 0.20 * 504 ~ 601, 601 < 610
    • Executed StatMan, an internal process which automatically maintains statistics. The process updated the stale statistics NCI_Products_ListPrice on dbo.Product table

      If we check the stats blob from the Step 2, we will see that the Updated column changed its value to the current date – the stats blob has been updated.
      The AutoStats event reported the UPDATE of the statistics with EventSubClass = 1 – Other. More on the event can be found here.

  4. Query Optimiser starts to generate the query plan – a plan for each query statement.
    • The second query in the batch has a predicate on the Name column of the dbo.Products table. In an attempt to make better cardinality estimates on the rows that needs to be processed, Query Optimiser decided to automatically create statistical information on the column.
      The system stops the batch compilation process and again executes the StatsMan process to create the new statistics.

      After creating the stats, QO decided not to use it  : (
      Below is the list of the “interesting statistics” loaded during the Query compilation process. The list does not include automatically created stats on the Name column.

      As a result of the updated statistics on the ListPrice column , the rowmodctr for the column was reset. 

    • QO sets the new recompilation thresholds(RT) for all tables used in the queries.
      1. RT(dbo. SalesOrderDetail) = 500 + 0.20(121317) =24763.4 (~24764)
      2. RT(dbo.Products) = 500 + 0.20(504)= 600.8(~601)
        This meas that QO will initiate query recompile due to “Statistics changed” reason if
        1. dbo. SalesOrderDetail
          1. 24764 or more inserted/deleted rows
          2. 24764 or more changes on: SalesOrderDetailID, ProductID columns
        2. dbo.Products
          1. 601 or more inserted rows
          2. 601 or more changes on: ProductID, ListPrice, Name columns
  5. The query execution starts. The query plans are constructed and cached. SP:CacheInsert event reported that the stored procedure has been cached.

Experiment 2 (stats change during the query execution)

In this experiment we will make “enough” changes to the Name column (dbo.Products table) HALFWAY THROUGH the stored procedure execution.

Step 1 Set up the environment

  • Run the script to reset the test environment
  • Add a WAITFOR statement between the two queries in the stored procedure
  • Use PowerShell to execute the stored procedure. Add HostName property. Use the HostName to capture only the events related to the PS call. This will prevent MS Profiler from capturing events related to the UPDATE statement that will run in parallel.
  • Add an ApplicationName filter to the Profiler trace (ApplicationName LIKE experiment)

Step 2, Run the PowerShell cmdlet, switch to SSMS and run the UPDATE queries below. The queries will generate enough changes to make the automatically created statistics on the Name column stale.

Step 3. Analyse the captured MS Profiler trace.
Figure 8, Query recompile

  • The first thing that is different from the last run is the SP:CacheHit event. The event shows that our stored procedure was found in the Plan cache. The previously set RTs and the interesting statistics are part of the cached information.
    NOTE: Auto created statistic on the Name column was not used during the initial query compilation – the stats are not part of the interesting stats.
  • This time there were no changes on the columns that would initiate statistics updates, no new auto created stats and the existing cached query plan does not need to be recompiled due to “statistic changed” reasons. The process proceeds with the query execution.
  • The first query is successfully executed following by the  WAITFOR statement. During the statement execution (6 seconds delay) a separate query has made enough changes on the Name column(dbo.Products) to pass the RT crossing test for the table and flag the auto created statistics on the column as stale. Even if not used by QO during the plan generation, the stats are marked as stale.
  • (1) The query execution stops at the  “Any stats stale?”  step . The System initiates the query recompile process – SP: Recompile due to 2 – Statistics changed reason. The event is followed by the statement level SQL:StmtRecompile event which indicates that only the second query needs to be recompiled.
  • (2) Again, the StatsMan process kicks in and updates the stale statistics. The RTs are set (in this case the number of row  has not changed ,hence the RTs stayed the same).Rowmodctr value for the Name column is reset. to 0 
  • (3) The AutoStats event reported Statistics Update  having EventSubClass = 1 – Other
  • (4) The SP:StmtStarting event reports that the second query has been recompiled and the batch execution continues.

Experiment 3 (tables with no stats on columns)

The experiment demonstrates how queries get recompiled when referencing tables with no statistics. The recompiles due to the “statistics changed” reasons are initiated by the RT-table cardinality crossing test results only.
As previously mentioned, the cardinality based RT crossing test is defined as

 | cardinality(current) – cardinality(snapshot) |  >= RT

Lets create a test table and a stored procedure to perform the above experiment.

Step 1, set up the test environment

Add some data to the table..

The initial statistical information looks like (find how to retrieve the metadata related to the statistical information at the beginning of the post)


Figure 9, rowmodctr with no statistical information

Step Run the stored proc for the first time. The RT is set to 500.

Step 3 Make enough changes to the table to pass the cardinality crossing test. Insert 500 rows. Do not use explicit transaction yet.

Step 3 Run the stored procedure again and observe the query execution behavior in Profiler.

Figure 10, Query recompile, table cardinality change – no stats

  • The new rowmodctr information looks like

    The new number of rows (rowcnt) is recorded along with the number of changes, rowmodctr=730. In this case the rowmodctr value is not relevant since the RT crossing test depends only on changes in the table cardinality. This will be more visible if we ROLLBACK the row insertion operation which will be covered later.
  • The second execution followed the “Cashe lookup = Success” path (see the batch compilation diagram) and failed to pass the very last step  “Any stats stale?“.
  • At this stage, the system has detected that the RT cardinality crossing test has passed due to the number of changes(new rows) inserted in the table.
  • The system stopped the execution process and  initiated the stored proc/statement recompile – SP:Recompile, SQL:StmtRecompile.  As in the previous examples, the reason for the recompile was 2 – Statistics changed.
    NOTE: The recompile process is not followed by the StatMan process since the query does not have any statsBlob information to be refreshed/created.

Experiment 3.1 (rowmodcnt not in use)

The next example shows that the RT cardinality crossing test is not related to rowmodctr as it may seem from the previous example where the number of changes followed table cardinality changes.

  • Follow the steps from the previous example.
  • Execute the INSERT query  from the Step 3 within an explicit transaction
  • Observe that there are no query recompiles due to “statistic change since there were no table cardinality changes – the ROLLBACK “canceled” row insertions.
  • The statistical information shows that the rowmodctr= 720.

Conclusion

Query compilation, execution and recompilation sequence among other steps includes; loading interesting statistics – the statistical information on different table columns that Query Optimiser may find useful when creating a good plan and auto-creating statistical information on the columns that participate in i.e WHERE filter, GROUP BY ..etc. 
Sql Server query engine also checks the validity of the loaded statistical information during the initial stored procedure compilation and again during the stored procedure execution phase. If the loaded statistics are found to be stale, the former pauses stored procedure compilation, refreshes(re-samples/refreshes) the loaded statistical information and continues compilation process. If Query engine detects stale loaded statistics during the execution phase,  the process stops, refreshes(re-samples/updates) statistics and restarts compilation process – query recompilation. The re-compiles are done per query not per batch.
The examples in this blog showed that the statistical information can be automatically maintained by the queries that use them. Statistics can be also maintained manually.
To mark statistics as “Stale”, QO uses the Recompile Threshold(RT) crossing test. The test tracks the number of changes on the significant(leftmost) columns within the statistic BLOBs. The information is stored in an ever-increasing, non transactionally consistent counter – “rowmodctr”.  The RTs are stored per table and within the compiled query.
The RT crossing test can be based only on the changes in the number of rows in a table.

 

Thanks for reading.

Dean Mincic

Client Requests & Sql events in Sql Server

Client Requests & Sql events in Sql Server


Summary

Very often we, the sequel guys, use MS Profiler/Sql Server’s Extended events to intercept and analyse the traffic between client applications and our precious Sql Server. Sometimes we capture an hour/day of traffic, and sometimes we just want to capture a slow running stored procedure’s  input param values.  Also, we are involved in  the data layer code reviews in order to keep Client data requests as optimal as possible. This post is a sort of an internal notes/documentation about different types of requests  that can be sent from  Clients to Sql Server and the corresponding events visible in MS Profiler. The article also gives a high overview on the space between ADO.NET and Sql Server

MDAC – Microsoft Data Access Components

To start off, lets first take a brief look at the MDAC framework and where ADO.NET sits in the stack. MDAC technology allows applications to communicate with almost any data-store.
MDAC architecture implements three logical layers:

  • Programming interface layer (ADO, ADO.NET)
  • DB access layer (ODBC, OLEDB, .NET Managed providers)
  • Data store

All of the layers are accessible through the MDAC API. (+ MS Sql Server network library)*


Figure 1, MDAC architecture

NOTE: Microsoft Network Library(Net-lib) is also part of MDAC and sits between TDS(Tabular data stream) Formatter and  the network protocol. The DLLs are specifically used by SQL Server to communicate with the Clients on the network level.  It supports the network protocols: Named Pipes, TCP/IP, Shared Memory, VIA).

ADO.NET

ADO.NET provides a generic interface(set of classes that expose data access services)  to a number of different data-stores (SQL Server,CSV, Excel..) from .NET applications. It is a set of libraries included in MS .NET Framework.
The main objectives of ADO.NET is to;

  • connect to a data source
  • submit queries
  • process results
  • provide a powerful disconnected data structure to perform data operations offline.

There are two main  components of ADO.NET for accessing and manipulating data

    • .NET Framework data providers – a set of class libraries that understand how to interact with specific data platform e.g Sql Server, or with a common data layer i.e OLE DB. Data providers transport data between proprietary data platforms and the generic ADO.NET data layer. ADO.NET framework includes three providers
      • The MS Sql Server Provider – exposed through the System.Data.SqlClient namespace
      • The OLE DB provider – exposed through the System.Data.OleDb namespace.
      • The ODBC provider – exposed through the System.Data.Odbc namespace.
    • DataSet – a class(System.Data namespace) that provides a disconnected representation of result sets from the Data Source. The object provides a consistent relational programming model regardless of the data source. It includes objects like: DataTable, DataRow,  DataView, DataColumn, PrimaryKey ..etc

The key classes within each provider(each provider has its own specific class names for the same objects) include:

  • Command (SqlCommand),
  • Connection (SqlConnection),
  • DataAdapter (SqlDataAdapter)
  • DataReader (SqlDataReader).


Figure 2, ADO.NET components, high overview

TDS (Tabular data stream)

TDS is an application layer protocol used to transfer tsql command between client and server. The protocol includes facilities for;  authentication and identification, encrypted negotiation, issuing of Sql batch(language events) and stored procedures(RPC) calls, managing and distributing the outcome of atomic transactions. TDS describe the names, types and optional descriptions of the rows being returned.   It was developed by Sysbase in 1984 and adopted by Microsoft in 1990. MS-TDS(Microsoft’s version of the protocol) specification can be found here.

Figure 3,Communication flow in TDS

More on how the Client talks to Sql Server

Client communicates with Sql Server in a layered fashion. Each layer exchanges information with its neighboring layer. Sometimes the layers can be bypassed.  Only the Transport protocol layer enables physical communication between Client and Sql Server. For all other layers the exchange of information is done locally – in RAM memory and  between different dlls.
The layers are:

  1. Application Layer (C# code, etc)
  2. High level data access API (ADO,ADO.NET…)
  3. Client data interface(OLEDB,ODBC, db-lib ..)
  4. Client TDS Formatter. The tsql commands sent to Sql server has to be in TDS format.
  5. Client net protocol (Shared memory, TCP/IP sockets, net-lib)
  6. Client transport protocol (TCP/IP ..)
  7. Server transport protocol (TCP/IP ..)
  8. Server net protocol (Shared memory, TCP/IP sockets, net-lib)
  9. Server data interface
  10. SQL Server

NOTES:  App level(A) can bypass ADO.NET  level(B) if we directly access teh Client data interface (direct API calls to OLE-DB, ODBC..etc).
Client protocol(E) and Client transport protocol(F) can be bypassed if the Client and Sql Server communicate through the Shared memory protocol. In this scenario Client and SQL Server run on the same machine. The components exchange information through the RAM memory space. The network elements are not required.

Client data requests

The only way clients can interact with Sql Server is by sending requests that contain TSQL commands for the database engine. The requests are sent over MS-TDS protocol(Microsoft’s version of TDS).
There are three main forms of the requests

  • Batch requests
  • RPC (Remote Procedure Requests)
  • Bulk Load Request

In the following examples I’ll use ADO.NET components to present the different  types of Client requests. I’ll  use MS Profiler to capture and analyse Events which corresponds to the requests.

Events

When Sql Server receives a message from a client(through TDS), it can be thought of as an event occurring – see  Figure 3, First client sends a connection request(a login event) and gets back success or failure response. Once connected, client requests typically fall into one of two categories:

  • Language events
  • RPC events

Language Events

A language event is a tsql batch sent from the client to the server. From ADO.NET perspective a tsql batch* is a set of tsql commands defined in the CommandText property of the SqlCommand Class. The command can be executed using one of the commands; ExecuteReader, ExecuteScalar, ExecuteNonQuery and ExectueXMLReader.

The commandType enum property of the SqlCommand Class specifies how the command string is interpreted. The Field values can be:

  • CommandType.StoredProcedure (contains the name of a stored procedure or a scalar function)
  • CommandType.Text (contains an tsql batch – one or more tsql statements, no GO directives)
  • CommandType.TableDirect (contains a table name. Only supported by the .NET Framework Data Provider for OLD DB)

NOTE: A tsql batch can be defined as one or more tsql statements before the GO* directive(batch terminator). This is specific to Microsoft SQL stack tools i.e SSMS, sqlcmd, osql. isql- Sybase It is not part of tSql language and may not be recognised by other similar tools. It is not permitted to use GO directive within CommandText property.
After a TDS request reaches SQL Server, the db  engine will create a TASK to handle the request. One task handles only one batch(a task may spawn a number of sub-tasks to support parallel executions). When ADO.NET “executes” a batch(one or more tsql commands), one TASK will handle the request. When SSMS executes i.e two batches(the same tsql command twice – GO 2, or two tsql statements divided by the GO terminator), Sql Server engine(SQLOS) allocates two separate TASKS for the job.

Non-parameterised batch request

This type of request does not have parameters. It can contain local variable declarations. The request is treated by Sql Server engine as an ad-hoc query.
Adhoc queries  can be cached and reused only if a subsequent batch matches exactly – exact textual match.  i.e 

The query plans above are  compiled and cashed separately. This behavior can lead to the problem known as “the cache pollution”.
Sql server optimiser may decide to automatically parameterise an ad-hoc query, but it’s very conservative when making those decisions. The query template must be considered to be safe, meaning that the same query plan doesn’t change even if the actual parameter values change – the paramterisation must not degrade query performances. Also, query engine decides on the auto-parameter data type (smallint in the example below). The datatype may be changed due to change in the input parameter size(PurshaseOrderId = 3420 can fit in 2bytes-smallint, but PurshaseOrderId = 210 fits into 1byte-tinyint). In that case the optimiser cashes another copy of the plan that includes the new data type.
In addition, many query elements disallow automatic parameterisation, such as; JOIN, IN, INTO, DISTINCT, TOP.. just to name a few.

Let’s execute the second query through a simple console application. The predicate value will be passed as a part of the batch.  Pass 707 as a command line argument; (ProductId = 707)
NOTE: We can also use SSMS to run the batch.

Figure 4, MS Profiler – tsql batch execution events 

The Client request is executed as a tsql batch. SQL:BatchStarting signals that the batch execution is starting.  SQL:StmtStarting event was fired for each statement in the batch(once in this example).

RPC Events

There are two basic ADO.NET client request types which invoke RPC(Remote Procedure Call) events

  • Parameterised batch request  – uses sys.sp_executesql Sql Server’s system extended stored proc
  • Stored procedure and  scalar user defined function call

NOTE: RPC(Remote Procedure Call) name came from Sybase and in context of the Client request represents a type of formatting of the query inside a TDS packet before it is sent to Sql Server. The requests are pre-formated by the driver/provider i.e OLEDB, ODBC,JDBC. ..etc
Windows RPC(Remote Procedure Call) is completely different technology which implements the interprocess communication(IPC) that allows applications to talk to each other locally or over the network. More on the RPC  here.

Parameterised batch request

Parameterised type of request does have parameter values passed to tSQL statements. Parameter input is treated as a literal value, not  as an executable code.
This type of request significantly improves the way Sql Server process the tsql commands. The sql batch  separates the “body” of the query from the data values managed by that query.
Lets change SqlCommand object from the previous example to use a parameterised tsql statement and see what happens.

Figure 5, MS Profiler – parameterised batch RPC event

This time ADO.NET constructs the request as a RPC(Remote Procedure Call) type. The client sends an RPC message data stream(TDS protocol level) to Sql server. The message contains: Procedure name( or in this case the ProcID) and the Parameters.  ProcID identifies Sql Server’s internal sp to be executed. In the example above ProcID = 10. The id value maps sys.sp_exeuctesql extended stored procedure in Sql Server.

Figure 6, sys.sp_executesql extended stored procedure

NOTE: We cannot use SSMS to invoke RPC event types since it’s not possible to send Parameters as a part of the TDS binary stream.

The parameterised batch request results with a cached plan, just like a regular stored procedure call.

Figure 7, parameterised batch request – cached plan

Stored procedure call

This type of RPC request is similar to the parameterised batch request. The main difference is that the commandType enum property of the SqlCommand Class is set to “StoredProcedure“, and the CommandText property value represents the name* of the stored procedure.

Quick note: In order to avoid cache misses/compile locks, use the two part naming convention when referencing  sql objects – dbo.uspGetPurchaseOrderDetails. More about sp caching can be found here.

Let’s encapsulate previous tsql batch in a stored proc…

and then modify CommandType and CommandText properties as follows…

Figure 8, MS Profiler – RPC Stored proc call

Using RPC: Starting and/or SP:Starting  events we can find out the value of the stored procedure’s input parameter(s).  It is interesting to notice the absence of the stored procedure’s ObjectId within the RPC call. The initial request doesn’t know whatID (object_id) is used by Sql Server to identify the stored procedure.

Not directly related to the topic but nevertheless interesting observation is the SP:CacheMiss event. The event describes the failed cache lookup for the stored procedure on the very first run as the plan was not generated and stored in the cache.

Now, let’s execute a  stored procedure that has a nested sp.

… add an output parameter to the code ..

From the Profiler’s trace below we can see that the only one RPC request was initiated for the top level stored procedure.

Figure 9, RPC request and nested stored procedures

From the trace above we can observe a few interesting things

  • Only the first, top level stored procedure call is initiated through the RPC event. This is the request initiated by ADO.NET.
  • The nested stored procedure call was captured through SP:Starting and SP:StmtStarting events. The input parameter values are not visible(more about this later).
  • RPC Output parameter* event is triggered AFTER the RPC:Completed event. This explains why we need to close Data reader object before retrieving the output parameter(see the c# code above)

NOTE: When the RPC is invoked, some or all of its parameters are designated as output parameters. All output parameters will have values returned from the server. For each output parameter, there is a corresponding return value, sent via the RETURNVALUE token. More about this can be found here.

How to capture nested stored procedure parameter values

In the example below, the nested stored procedure call was captured through the SP:Starting and SP:StmtStarting events. it is not possible to capture nested procedure(s) input parameter values only by examining this two events. Sql Profiler is not a debugging tool and it shows only what has been executed. This means that it can show only the parameters values that are initially passed from the data layer, not during the procedure execution.
So how can we capture a nested stored procedure input parameter values?  Well, we can get the values if

  • The top level stored proc parameter(which we can get through the RPC event) value is passed unchanged to the nested sp.
  • The nested stored proc parameters are passed as literals i.e  .. EXECUTE dbo.MyStoredProc @name='John Doe', @Age=42 ..

However, there is another, more interesting way to capture the parameter values.

We can include the Showplan XML Statistic Profile  event class to our trace. The event class triggers when Sql Server executes an SQL statement and shows complete, compile-time data, including the parameter values we are interested in.

Figure 10, Showplan XML Statistic Profile event class

We can export the plan(XML format) and then search for the ParameterList element.

Now we can analyse the parameters’ runtime/compiled values and the hunt for the parameter sniffing issues can begin 🙂

NOTE: Showplan XML Statistic Profile is an expensive event to track. It may be a good idea to use the server side tracking instead or the Profiler UI. ..

Conclusion

In my opinion,  It is beneficial for the Sql database developers to be familiar with the database access patterns from the client end. Knowing how different components i.e ADO.NET, OLEDB, ODBC, TDS etc. fit together can help when making design decisions. The way Client constructs its data requests dictates the database engine behavior i.e Sql Server treats non-parametersied queries as ad-hoc queries whereas it caches the execution plans for the parameterised queries the same way as it does for stored procedures. Understanding how different events( captured by Profiler or Extended events) relate to the client requests can help us find and understand the root causes  for the slow running queries, excessive locking etc. that may not be on the Sql Server side but on the data layer.

Thanks for reading

Dean Mincic

 

 

 

Sysname datatype and NULL column constraint

Sysname datatype and NULL column constraint


Sysname is a system supplied user defined datatype that is functionally equivalent to NVARCHAR(128). The unicode data type may be used to reference database object names.  The maximum length of the Sql Server object names is 128 unicode characters with an exception of the local temp tables*

*The maximum length of a local temporary table name is 116(N’#’+115) unicode characters. The “missing” 12 characters belongs to the hexadecimal  value appended to the name. The value makes the temp table names unique across an Sql Server instance.

When we create a table, by default, the columns can store NULL values.
Dynamic query below creates a table with 34 columns. Each column is of a different Sql Server data type.


Figure 1, Create table script

We didn’t explicitly specified the NOT NULL column constraints. This means, by default, that it’s possible to store NULL values in the columns (the columns are nullable). However, column COL26_sysname  refuses to follow the rule 🙂

Msg 515, Level 16, State 2, Line 108
Cannot insert the value NULL into column ‘COL26_sysname’, table ‘tempdb.dbo.DefaultColumnConstraints’; column does not allow nulls. INSERT fails.

The statement has been terminated.

A Column of a SYSNAME data type is not nullable by default. To allow NULL values to be stored in the column, we need to explicitly specify the nullability of the column.

After the change the insert query executes with no errors.

Fgure 2, Nullable Columns

Timestamp is another data type that does not allow NULL values by default.

The query below selects all non-nullable columns (by default).


Figure 3, Not nullable datatypes by default

Side note: 
TIMESTAMP is the data type synonym for the ROWVERSION datatype(Sql Server 2012+). A ROWVERSION is automatically generated, unique 8b binary number within a database. It is simply an incrementing number generally used to indicate a row version.

Columns of the ROWVERSION data type automatically assign a new, unique binary number. It is not possible to insert any value except NULL (which then gets replaced with a proper binary number). Column NULL  constraints does not work with the ROWVERSION data type.


Figure 4, Rowversion data type

A question for the audience would be; why rowversion is the only Sql Server system data type that is represented with its synonym, timestamp, in sequel’s metadata

FIgure 5, timestamp vs rowversion

Conclusion

By default, all Sql Server system data types are nullable when assigned to the table columns – except sysname datatype. In case of SYSNAME, the default behavior does not allow NULL values. It is a good practice to explicitly include NULL constraints (nullability) when creating a table.

Thanks for reading.

 

XACT_ABORT and Query Timeout in Sql Server

In this blog I have explored how XACT_ABORT setting controls Sql Server behaviour when it interacts with Desktop and Web applications, in the situation of a query timeout runtime error. It is particularly interesting to see how Sequel works with the web applications that use the connection pooling mechanism in those conditions.  I also briefly covered MARS(Multiple Active Result Sets) technology and how it relates to XACT_ABORT.

The performed tests demonstrate the behaviour of a typical stored procedure when executed in a session with the XACT_ABORT set to ON/OFF and in the query timeout situation. The tests covered a Desktop -SSMS  and a web application.

Here is a bit of theory we need to know in order to understand the test results.

XACT_ABORT
Is one of the parameters that define the current session behaviour.  The parameter belongs to the group of Transaction statements along with: IMPLICIT_TRANSACTIONS, TRANSACTION ISOLATION LEVEL and REMOTE_PROC_TRANSACTIONS (deprecated in Sql Server 2014). More about the parameter can be found here.

Query Timeout

The queries executed on client side may be cancelled during the execution after a certain period of time. One of the reasons can be the “query timeout”, scenario in which the app. code decides to cancel the ongoing action, if the action takes more time to finish than expected(defined).

Query timeout is a client-side concept. After a certain period of time, a client, more specifically db provider will raise an Attention event which will signal the query timeout to the Db Server.  At the next available opportunity, Sql Server will stop/abort the currently executing query in the context of the current connection. The sudden stop will not raise any Sql server errors.
XACT_ABORT defines how Sql Server handles the ongoing transactions in these situations.
It is worth noting to mention the Remote query timeout(Exec sp_configure ‘remote query timeout’). This server scoped setting is related only to the queries executed by a remote source. e.g Linked server.

In a situation where Sql server is “instructed” to stop query execution during Update/Insert/Delete actions within an explicit transaction, there is a possibility that the ongoing transaction stays open(abandoned). As a result, a number of objects(sql server resources) may remain locked and not available to other queries. By default XACT_ABORT is set to OFF. This means that In the case of the timeout, SQL Server will let the caller(the app. code) to handle the uncommitted transactions.
The application code may be designed to handle the exceptions by rolling back or, if possible, committing  the interrupted transactions and closing the connection or it can just simply close the connection assuming that all the opened transactions in the scope of the connection will be automatically rolled back*.

*Just a small digression: From Sequel’s point of view, the scope of a transaction is a session, and from the clients’ point of view the scope of a transaction is a connection.
In Sql Server a session may have zero, one or more* related connections. Sql Server engine internal processes(SPID<=50) do not have related connections. In case of MARS (Multiple Active Result Sets) a session is related to multiple, hierarchical connections. The Client’s connection is parent connection and the child connections are logically scoped as “one per batch”. Consequently, the scope of a transaction within the MARS enabled connection is a batch – Batch scoped transactions. This is the case when the MARS Session is in the “Local Transaction Active” state – the state in which all the statements executed in a session run under an explicit or implicit transaction.
The hierarchical organisation of the transactions can be  examined by using dynamic views i.e sys.dm_exec_connections view. The significant columns would be: net_transport, parent_connection_id , connection_id.
MARS technology is interesting to research and to blog about and certainly cannot fit in a “small digression” 🙂

Session Ids’ are recyclable and are related to the unique transaction IDs.

Connection Pooling

Connecting to the database is resource intensive operation . Every time  a client wants to interact with a database it has to establish a new connection to it (to initiate a  new physical channel-socket, parse the connection string, perform db authentication etc). Because of the disconnected nature of the web based  applications, the connections are closed as soon as client is finished with the db request. Constant opening and closing connections wouldn’t  be a problem if there were a small number of clients who  don’t interact with the db often. In reality, there is a large number of concurrent clients fighting for the server resources.
The idea behind the Connection Pool(CP) mechanism is to allow already existing connections to be reused by the clients. Essentially, CP is a container object which contains a list of connections defined by the same connection string. A connection in this context is a pointer to the memory location where the connection object is stored.

Connection Pools are controlled and maintained by the database providers, like .NET Framework Data Provider for Sql Server or ADO.NET set of data access components based on the provider. Connection Pooling is active by default(even if not specified in the connection string). The Pool properties are a part of the connection string properties(key-value pairs).
More about connection pooling and pool fragmentation can be found here.

Another thing that would be interesting to explore is the sequence of events between a web application and Sql server during the connection pooling. The following is one of the typical scenarios.

  1. A Client requests data from SqlServer. There is no CP container defined based on a connection string that will be used to define the connection. Client calls the Open() method  of a connection object  e.g based on SlqConnection class if using .NET Data Provider for Sql Server)
  2. SqlServer authenticates the user and stores the connection/sql session data. The Audit Login event shows;  sessionid, EventSubClass =”1- Nonpooled”, Connection type  = “1- Non DAC” …etc. The requested connection is not part of the connection pool yet.
  3. Client executes the tsql batch and closes the connection (Close() method of the connection object). Even if enclosed e.g in the “using” structure, the connection object won’t be  destroyed but only referenced by a pointer now stored in a newly created connection pool object container. The object lives in the app. server memory. At this point,  Sql server is not aware that the client closed (returned) connection to the pool. From sql server point of view, the connection is still open. This also means that the abandoned(not committed) transactions, if any, will remain open – This will be a part of the following tests :)
  4. The same or a different client requests to open() the same connection. The code will not create(instantiate) a new connection object. Instead, the pool manager will provide the memory location of the exiting connection object. Again, Sql is not aware what’s happening on the client side and still keeps the information about the original connection.
  5. The client now executes tsql batch e.g using Sqlcommand /ExecuteNonQuery object/method   in the context of the connection. It is only at this point that Sql Server receives the information about the connection being reused by someone.
    • a) The event Audit Logout is fired indicating that the existing connection is pooled. The EventSubClass = “2 – Pooled”.
    • b) The data access API layer(in this case SqlClient) executes  system stored procedure sp_reset_connection (the sp is not available through tsql) to clean* the existing context of the connection and re-validate the authorisation of the  user-principal  through Audit Login and Audit Logout events.  In this context, cleaning a connection context means cleaning up SqlServer’s session context i.e rollback any active transaction that may have been left open through this session, dropping any local temporary table which has been left behind by the previous owner of the connection, closes any open cursors and deallocates the resources it has been using, resets the CONTEXT_INFO, etc);
    • c) The Audit Login event fires up, again indicating the nature of the connection (EventSubClass = “2- Pooled”)
  6.  SqlServer executes tsql batch.
  7. Client calls Close() method and the connection is again returned to the connection pool. (the pointer to the connection object is now available for the next client)
Test case scenarios:

I’ve performed the following tests to investigate how Sql Server reacts with different XACT_ABORT settings. The client applications will initiate a query timeout in the middle of an explicit, ongoing transaction encapsulated in a stored procedure.

Test 1: Desktop application query timeout. (MARS test included)
Test 2: ASP.NET application query timeout with connection pooling ON

Desktop based client application query timeout

XACT_ABORT OFF (Default)

For this test I used SSMS as a Windows  based client app. To prepare for the test, create a test environment using the script below:

Stored procedures:

SQL Server Profiler:
I’ll use SQL Server Profiler to capture the Attention event when sent by the client application.   Add Error And Warnings/Attention event to the Standard(default) set of the traced events.

SSMS:
SSMS will act as a Desktop client which will cause the query timeout. To simulate the scenario open(CTRL+N) three sessions.

  • Session1 – Change the Execution timeout from 0(unlimited) to 3s . The session will be used to run the sp that will cause query timeout (SSMS:RIght click/Connection/Change Connection)

    ssmsexectuiontimeout

The code below will be terminated by the timeout.

  • Session 2– The session will be used to run the second sp that will be reading from the same table used by the procedure initiated in session 1.

  • Session 3– Add the code below to monitor the transaction state and the locked resources.

To begin the test ,enable the Profiler trace and execute code in the session 1 and then in the session 2(sp that just selects data) and finally execute the code in the session 3.

test1a

Analysis:

The sp(Session 1) will take more time(~10s) to execute than the Client’s execution time allows (3s). After 3s, the client sends  an Attention event to Sql server which causes Sequel to immediately stop the sp execution, with no error. Because XACT_ABORT is set to OFF(default), Sql Server will leave the transaction open and let  the Client handle the commit/rollback.

The client’s event handler will send the following error message:

Msg -2, Level 11, State 0, Line 3
Timeout expired.  The timeout period elapsed prior to completion of the operation or the server is not responding.

Profiler -spids may be different (spid 55 is spid 60 on the previous image)profiler1

Now, the sp that runs in Session 2( reads all rows from dbo.Products) has to wait since the session 1’s active transaction(xactTest) holds X(Exclusive) lock on the KEY(the table is a clustered index) and  IX(Intent Exclusive) on the table(object) which is not compatible with the S(Shared Locks) requested by session 2.
The “SELECT” stored procedure will just wait indefinitely(the default execution time for that connection is unlimited).
Session 3 can be used to analyse the open transactions, locked resources etc..
If we now disconnect the Session 1(right click/Disconnect), Sql Server will automatically ROLLBACK all ongoing transactions within the closed connection scope, leaving the DB in the coexistent state – SSD price will not decrease by 10%   :). The stored procedure in the Session 2 will finish and if we re-run the code in the session 3 we’ll see that there are no abandoned transactions. All relevant resources will be freed.

Programmers usually use the “using” statement to “wrap” the objects used for the communication with Database. The structure ensures that all of the objects instantiated within the block will be removed, closed, flushed, disposed etc.(C devs won’t like this kind of a black box 🙂

The error handler will handle the timeout and the code will exit the structure closing the connection. Sql server will then automatically rollback all opened transactions(within the scope of the closed connection) leaving the db in the coexistent state. This will happen regardless of the XACT_ABORT setting.

To show the difference between XACT_ABORT set to ON/OFF  we can set a break-point at Line:21(any line inside the catch block). With the xact_abort set to OFF the uncommitted transaction will remain open until the code exits the structure. With ON, Sql server will rollback the opened transactions immediately after receiving the Attention signal and before the break-point. This can be monitored through the Session 3 code as mentioned earlier.

XACT_ABORT ON

To test the same scenario with the xact_abort on, reconnect the Session 1(Right click/connect – now, the default execution timeout is 3s) and include the third input parameter

This time Sql server is set up to handle the uncommitted transactions, and when a run-time error occurs – query-timeout in this case, it will rollback the transactions. Session 2 will be able to execute its code. Session 3 will show the “empty resultsets” – no locked resources 🙂

MARS Enabled

Xact_Abort ON/OFF  setting has a different effect on the MARS-enabled connection in the example above.
To test this scenario change the Session 1 connection properties and add an additional connection parameter: MultipleActiveResultSets=True

If we run the test again the results will show that XACT_ABORT setting does not affect the sql Server behaviour* in case of the query timeout run time error. The explicit transaction will be automatically roll back. Session 2 shows us the MARS transactions hierarchy within the same session.
*The behaviour would be different if we executed the stored procedure logic as a script and with no explicit transaction. 

ASP.NET application query timeout with connection pooling ON/OFF

The following test demonstrates Sql server’s behaviour in case of application timeout when xact_abort is ON/OFF in combination with the Connection Pooling TRUE/FALSE

The test environment:

  1. Simple web application that can perform a) select and b) update actions on a database using one of two available connections – one connection authenticata using Integrated* security and the other one uses Sql Server authentication.
  2. Windows Performance Monitor (perfmon.msc) – to examine connection pool counters
  3. Sql Profiler – for tracking events triggered by the app and data provider.
  4. Sql Server tsql code to track active connections, locks etc – Session 3 code from the previous example.

Note: The integrated security will use ApplicationPoolIdentity(AP) to connect to the db. Execute the script below to create a Login for the AP identity and a Login for an sql server user:

The Web app.

The interface allows you to use two different connections to select and update the existing data. The update will cause the timeout run-time error.

The results of the select statements will be displayed in the Grid view

The error message will show under the grid view control.

 

 

The code is similar to the code used in the previous example.

Test: Two clients use the app. The first runs an expensive Update which causes the time-out, and the second one tries to Select data from the same table. Both clients use the same connection.Connection Pooling is enabled.

Test preparations:
Open two instances of the web application in two browsers. Run the tsql code from the previous example that selects the open transactions, Open SQL Profiler (standard trace + Errors/Attention event, Audit Login/ Audit Logout). Include Filter for ApplicationName in (WINXactAbort, SQLXactAbort). Open Performance Monitor and add .NET Data Provider for SqlServer Counters (example).

Analysis:

  1. Two different clients using the same connection type e.g Integrated Security authentication, performs the following actions:
    •  1.1  Client1 updates a product price(Update Products). 1st non-pooled connection established.
    • 1.2 During the execution Client2 tries to read the product prices (Show Products). 2nd non-pooled connection established(EventSubClass =”1- Nonpooled”,). Client2 has been blocked by the Client1’s update process. Client2 waits.
    • 1.3 Client1’s update action times-out (simulates a long running query) leaving the products table locked by an uncommitted-abandoned  transaction. Attention event raised. Close() method executed. A new CP container has been created. The client “returns” the connection to the newly created CP.  Sql Server thinks that the connection is still active. The CP now has one connection ready to be reused.
    • 1.4 Client2 still waits for Client1 to finish with the update and to unlock Products table. Eventually, Client2 times out (default command timeout = 30s). The connection is now returned(referenced by a pointer) to the CP. Connection pool now has 2 connections ready to be reused. The Sql Server resources(products table) is still locked by Client1.
    • 1.5 At this point, Connection Pool has two available (idle) connections. The first still has a non-committed transaction in its context. If a new client, Client3 tries to read the same data, CP will allocate the last connection available using the LIFO(Last In,First Out) algorithm. In this case, the allocated connection will be the one which originally belonged to Client2. As expected, Client3 will get blocked by the same abandoned transaction. Moreover,no client will not be able to access the Products table until the status of the transaction in question gets resolved (rollbacked/committed).

This scenario is common and can cause a lot of frustration since the effects can vary i.e sometimes works, sometimes doesn’t work 🙂

To add to the confusion, sometimes the situation can resolve itself e.g: CP will remove idle connections from the pool after 4 to 7min of inactivity by triggering the Audit Logout event which will,among other things, finally instruct SQL Server to rollback the outstanding transactions in the context of the destroyed connection(session). Another possible scenario is if the  “doomed” connection gets reused by a new Client. In that case the sp_reset_connection stored proc(mentioned earlier) will  instruct Sql Server to “clean the mess” and prepare the clean connection/session context for the new Client.

Profiler – the trace shows the above sequence of events

Connection, session and transaction metadata

The situation can be avoided using the following approaches:

  1. Setting XACT_ABORT to ON. This will instruct Sql server to take action of rolling back the ongoing transactions after receiving  the Attention event as a result of the command timeout issued by the client.
  2. More thorough data layer coding ie.  execute the queries within the properly defined transactions. Properly handle the uncommitted transactions within the catch block.

Both techniques will prevent the unpredictable behaviour explained above.

XACT_ABORT ON

To set up the Xact_abort ON change the value of @SetXactAbort  parameter to 1 and repeat the test.

The same test shows that as soon as Client1 raises the Attention event, Sql Server stops the code execution and performs rollback on the ongoing transaction. All subsequent read requests(Client 2,3..) will be successful.

Using Connection Transactions 

To test the scenario change the bthUpdateProducts_Click  event to to include transactions. and set parameter @SetXactAbort back to 0.

This time the code will rollback the transaction within the catch block and the resources will not be blocked. If we now set XACT_ABORT  to ON, and repeat the same test, after the Attention event,  SQL Server will Rollback the transaction (@@Transccount = 0) and the code will skip to execute Rollback() method because the Connection property of the transaction object t1 returns null since the transaction is not longer valid.

Conclusion

It is important to understand the XACT_ABORT setting to be able to prevent and/or explain Sql server’s behaviour in case of a query timeout run-time error.  When set to OFF, the default value, Sql server will let the client to handle the timeout situation and to take care of the connection elements i.e ongoing transactions. Query timeouts are the Client-side concept only and Sql Server does not treat them as errors. As soon as possible, after receiving the Attention event, Sequel will stop the execution reporting no errors. If XACT_ABORT is set to ON, sql server will rollback unfinished transactions and then return to the Client.
Desktop applications may use different approaches when dealing with the db connections. Some applications may handle the query timeout and close the connection(dispose the connection object). This instructs Sql Server to rollback all unfinished transactions in the scope of the session/connection. In this context XACT_ABORT setting will not have direct effect to the execution. Other applications e.g SSMS, will keep connections open after handling query timeouts. In this case the abandoned transactions may cause other requests to wait to acquire required locks and the problem can escalate. In this context XACT_ABORT’s value “ON” will rollback the abandoned transactions preventing the resource locks.
Web applications usually use the Connection Pooling technology to optimize database authentication process. The connections(connection objects) will stay “live” and ready to be re-used by other clients. Every CP contains a collection of the similar Connections – connections with the same connection string. The connections availability follows the LIFO(Last In, First Out) algorithm. For example, if we have a Connection Pool CP1 with  4 connections in it and  ready to be reused CP1 = {c1,c2,c3,c4}. Connection c3 has left an abandoned transaction leaving table T1 locked. Scenario1: A client wants to read data from T2. CP1 will provide the client  with the connection c4. The client clears  the connection/session context left from the previous owner and reads the data with no problems. Scenario2: A client wants to read data from T1. CP1 provides connection c4. After clearing the c4 context the client gets blocked by the abandoned transaction left in the context of the c3. This can cause another timeout.   Scenario3. A client wants to read T1, gets c4, clear the previous context and ends up blocked. At the same time another client wants to read T1. Now CP1 serves c3 to the client. Client clears the connection’s previous context which includes the abandoned transaction rollback. The latest client now can read T1 as well as the previous one.

MARS Enabled Connections may affect SQL Server behaviour in the case of a query timeout since the technology changes the scope of transaction – Batch scoped transactions. This exiting technology is something I would like to blog about in one of the future posts.

There are many case scenarios in which the query timeout can cause confusion and the unwanted results. There are two main approaches to resolve this; a) more thorough coding on the client side which includes proper error handling and use of the connection transactions. b) using XACT_ABORT ON on the Sequel side which will handle the abandoned transactions.

My personal preference is not to rely on the Client’s code and to always use XACT_ABORT set to ON when needed. During more than 10 years of database programming, I have worked with only a handful web programmers who were interested in this matter. In most cases, their perception of a database is a simple data store, preferably “controlled” by an ORM framework. After a certain period of production life, these “Agile products” usually become slow, not responsive and sometimes unpredictable. The Connection pooling/query timeout problem is one of the unwanted scenarios. From our(DB Devs) perspective this may not necessarily be a “bad thing” since we all get a “good dollar value” for repairing the mess afterwards… but this can be an inspiration for another, more philosophical post  🙂

Thanks for reading.

Dean Mincic

Orphaned DB Users and Sql Server logins


One of the common tasks in db community is moving databases from one Sql server instance to another.
For simple environments, it could be just a matter of backing up  database on one server/instance and restoring it on another.

Sometimes, even if we successfully restore database on a new server, create all necessary logins and change the application connection string to point to the new instance we still get the Database not accessible or Login failed error messages.

The common reason for the errors is the disconnection between the db users and their logins – The orphaned DB users.
The technique we usually use to re-connect the users, is to call a system stored procedure that will do the Login-DbUser remapping.

Why does the problem occur in the first place and what we can do to prevent it. The following is a little bit of theory and a couple of examples that will illustrate the problem.

In Sql Server, there are eleven different database user types. The type I am focusing on today is:  Db User based on the SQL Server authenticated Login . The complete list can be found here.

Every principal (entity that can request SQL Server resources) has two main properties:

  • Principal ID or ID
  • Security ID or SID

The scope of influence of a principal depends on the level that the principal operates on e.g Sql Server Level principals operates on  an Sql Server Instance level while the Database level principals operates on a database level.

  • Logins are principals whose scope is Sql Server instance
  • DB Users are principals whose scope is Database
DB Users –  based on Sql Server Logins

When  we create an Sql Server  Login,  Sql Server assigns ID and SID to the created principal.

  • ID – (INT) -Uniquely identifies Login as an Sql Server securable (resource managed by Sql Server). The ID is generated by Sql Server
  • SID – (VARBINARY(85)) –  Uniquely identifies the security context of the Login. The security context depends on how the identifier was created. The Login  SIDs can be created by :

    • Windows User/Group. The SID will be unique across the User/group domain and will be created by the domain.
    • Sql Server. The SID is unique within Sql Server and created by Sql Server – used in the example below.
    • Certificate or asymmetric key. (cryptography in Sql Server will be covered in one of the following posts)

The information about the Logins are stored in the master database

The following code will create a few Sql objects to illustrate the problem.

The logins are stored in the master database and can be viewed using sys.server_principals system view:

Query Results (the identifiers may be different on different PCs)
Logins_srvPrincipals

Now we need to create a few database users.

As mentioned before, there are eleven different types of database users. For this exercise we’ll create db users based on  Sql server logins.

Sql Server has  assigned the Principal IDs and Security IDs to the newly created users.

  • ID – (INT) -Uniquely identifies db users as a database securable.
  • SID – (VARBINARY(85)) – Uniquely identifies the security context of the User. The security context depends on how the identifier was created – In the example the db Users security context depends on the Logins and therefore the User SIDs will match the Login SIDs .

The information about the database users are stored on database level an can be viewed using the sys.database_principals system view.

Users_DB1

..and for the second database..

Users_DB2

The diagram below shows the relations between Logins and Users.

LoginsUsers

Image 1, Logins/Users mapping

Case Scenario:
An application uses two databases, TestOrphanedUsers_1 and TestOrphanedUsers_2. We decided to move the application’s backend to a new instance by backing up and restoring the two on the new server.
The restored databases contain all of the previously defined db users since the principals are a part of the databases. The original server logins were not transferred because they belong to the original master database.
At this stage the logins are not mapped to the users and the application is not able to access the backend.

To simulate the scenario, we’ll remove the previously created logins.

If we removed the logins using SSMS UI, we would get a message

DropLoginMsgSSMS

The users left in the databases are now called “The orphaned Users”. The users without the corresponding logins cannot be used to access the databases. This situation mimics the database restore on a new Sql Server instance.

The next step is to create new logins. At this stage we can do two things.

  • Create new logins (as we did before). Sql server’s engine will assign new SIDs to the logins. These identifiers will not match the existing user SIDs and consequently we’ll have to remap the Logins to the Users (to make SIDs match). To make a match, the process will replace the old user SIDs with the new Login ones .

Using the principals’ metadata we can see the mismatch between SIDs .

Login SIDs:
Logins_srvPrincipalsNEW_notMatch

To restore the previous mapping (see Image 1) we need to remap the orphaned users as:
Logins_UsersMapping

.. using the sys.sp_change_users_login system stored procedure.

This will replace the user SIDs with the new Login SIDs
The stored procedure supports Auto_Fix action type that can be used in a specific scenario in which we create a missing login with the same name as the orphaned user the login was created for.
More information about the procedure can be found here.

NOTE: SQL Server 2016 is the last database engine version to support sys.sp_change_users_login procedure.
Microsoft recommends to use ALTER USER instead.

  • Create logins implicitly specifying  SIDs to match the db. user SIDs,

Now we can test the mapping using the Logins to access the databases.

Conclusion:

The database users created for(or based on) Sql Server authenticated logins must have a valid link to the logins. The link is the Security identification(SID) varbinary.
Due to different scopes of the principals, db Users, when restored on a different server, may became disconnected(orphaned) from the corresponding Logins(the new logins may have new SIDs that don’t match the original db User SIDs). In this situation the applications are not able to connect to the database.
To remap the principals we can use two approaches; system sp  sys.sp_change_users_login to change the db user SIDs to match the new Login SIDs  or to create new Logins using the original user SIDs.
It’s worth mentioning that the latter may cause the “Supplied parameter sid is in use” error if the specified SID is already in use by an existing Login.

Thanks for reading.

Dean Mincic