Tag Archives: #SQLServer

All about Microsoft SQL Server

#0208-SQL Server-SET options-NOEXEC v/s FMTONLY-Does FMTONLY really execute the query/workload?


It’s a great feeling when you, the kind reader, share your feedback on my posts because generally, these provide a lot of learning opportunities for both. In the last couple of weeks, I explored the following SET options:

  1. PARSEONLY
  2. NOEXEC 
  3. FMTONLY (SQL Server 2008 R2 and below)
  4. sp_describe_first_result_set – replacement to FMTONLY (SQL Server 2012 and above)

SET options allow us to change the behaviour of SQL Server for the current session with respect to handling of specific information like date and time values, locking, Query execution, transaction, ISO settings and Statistics. While the SET option for PARSEONLY is quite straight-forward, a confusion may arise between NOEXEC and FMTONLY. Here’s why:

  • NOEXEC – parses a query, produces and adds to the plan cache the execution plan of the query/workload in hand, without executing the query
  • FMTONLY – parses the query, produces the execution plan and executes the query/workload to return the meta-data associated to the query without processing any records

When the FMTONLY option is exercised, the query is actually executed to return the meta-data, but no records are processed. However, this behaviour is not intuitive. Here’s a follow-up question that I received in my post related to FMTONLY.

When you try to execute a query that have side effects (like an INSERT) with FMTONLY ON, you can easily check that the row is NOT inserted. I just tried this on SQL 2008 (not R2). Can you confirm this? If this is true, how is FMTONLY different from NOEXEC?

Demo

In order to answer this question, I have come up with the following demo. The demo simply involves using the NOEXEC and FMTONLY options on a query around a non-existent table – MyTable. Since the table is non-existent, I should encounter a run-time error the moment the query is executed. The script below does the following:

  • Sets the system to a base state where both NOEXEC and FMTONLY are set to OFF
  • A query around the non-existent table – MyTable is executed with the NOEXEC option turned ON
  • The same query is re-executed with the FMTONLY option turned ON
USE tempdb
GO

--Base State
SET NOEXEC OFF
GO
SET FMTONLY OFF
GO
PRINT '00. Setting base state - both NOEXEC and FMTONLY are now OFF.'
GO

PRINT '01. Now checking whether MyTest already exists or not.'
PRINT '    If the ObjectId is not printed after this line, object is non-existent.'
PRINT OBJECT_ID('MyTest')


PRINT '02. Running with NOEXEC ON now...'
--Set the NOEXEC option to ON, telling the database engine
--to Parse and Compile the query, but not execute it
SET NOEXEC ON
GO

--Test workload.
--NOTE: The MyTest table does not exist!
SELECT Id,
       MyValue
FROM MyTest

SET NOEXEC OFF
GO

PRINT '03. NOEXEC is now OFF.'
PRINT '04. Running with FMTONLY ON now...'

--Set the FMTONLY option to ON, telling the database engine
--to Parse, Compile, Execute the query, 
--and return meta-data, but not return any records
SET FMTONLY ON
GO

--Test workload.
--NOTE: The MyTest table does not exist!
SELECT Id,
       MyValue
FROM MyTest

SET FMTONLY OFF
GO

PRINT '05. FMTONLY is now OFF.'
GO

Running the entire script against my test SQL Server instance (tested on SQL 2008, SQL 2008 R2 and SQL 2012) yields the following results.

00. Setting base state – both NOEXEC and FMTONLY are now OFF.

01. Now checking whether MyTest already exists or not.

    If the ObjectId is not printed after this line, object is non-existent.

 
02. Running with NOEXEC ON now…

03. NOEXEC is now OFF.

04. Running with FMTONLY ON now…

Msg 208, Level 16, State 1, Line 4

Invalid object name ‘MyTest’.

Conclusion

The above was a very simple demo, with a very clear output which helped me arrive at the following conclusion:

  • Although the table is non-existent (as confirmed by the OBJECT_ID() call in step #01), NOEXEC did not return any errors
    • This indicates that NOEXEC did not actually “submit” the query to the query engine for execution
  • The  attempt with the FMTONLY option set to ON however, did return a runtime error and that resulted in batch termination (no statements after that point were executed)
    • This indicates that FMTONLY did execute the query and as a result, encountered the error

Now, because the attempt with FMTONLY resulted in a batch termination, allow me to return my server back to the base state.

(To know more about SQL Server error states, please visit Pinal Dave, a.k.a. SQLAuthority’s [B|T] post: Introduction to SQL Error Actions – A Primer)

--Base State
SET NOEXEC OFF
GO
SET FMTONLY OFF
GO
PRINT '00. Setting base state - both NOEXEC and FMTONLY are now OFF.'
GO

I trust that the above demo answers all questions that one may have regarding the differences between NOEXEC and FMTONLY. If you have any other questions, please feel free to send them over to me. I will be glad to help!

Until we meet next time,

Be courteous. Drive responsibly.

#0207 – SQL Server (2012 and above) – sp_describe_first_result_set – replacement to FMTONLY


Earlier, we discussed a situation wherein the database objects (an ad-hoc query, stored procedures, functions, etc) need to supply meta-data to the calling applications so that the format of the response can be tested without actually running the query. ADO uses this mechanism to make a “dry-run”.

In SQL Server 2008 R2 and below, one SET option came in very handy in realizing this requirement. This option was the FMTONLY option. The FMTONLY option is marked as a deprecated feature in SQL Server 2012, and is replaced by:

  • sp_describe_first_result_set
  • sys.dm_exec_describe_first_result_set
  • sys.dm_exec_describe_first_result_set_for_object

sp_describe_first_result_set

You can revisit the discussion related to FMTONLY here. The core requirement is that at execute time, the SQL Server database engine should parse (PARSEONLY), compile (NOEXEC) and executed a query, but return only meta-data back to the client application. No data rows are to be returned. Please note that the name of the procedure suggests that information is returned only for the first result set (this could be applicable in case your procedures return more than one result set/MARS).

Here’s how the sp_describe_first_result_set stored procedure can be used to get this information:

USE AdventureWorks2012
GO
--SQL 2012 and above only!
EXEC sp_describe_first_result_set @tsql = N'SELECT Employee.BusinessEntityID,
                                                   Employee.BirthDate,
                                                   Employee.Gender,
                                                   Employee.JobTitle
                                            FROM HumanResources.Employee AS Employee'
GO

One of the first things we see is that the result set is much more comprehensive and user-friendly when compared with the older FMTONLY.

Result set for sp_describe_first_result_set

The extended stored procedure also accepts:

  • A set of parameters (@params), similar to sp_executesql
  • A @browse_information_mode parameter which has the following possible values:
    • 0 = No information is returned
    • 1 = Query is analyzed as if it contains the FOR BROWSE option specified
    • 2 = Query is analyzed as if it would be used in preparing or executing a cursor

Return Value information:

  1. When called from T-SQL, sp_describe_first_result_set will always have a return value of 0
  2. If the procedure throws an error and the procedure is called as an RPC, return status is populated by the type of error described in the error_type column of sys.dm_exec_describe_first_result_set

sys.dm_exec_describe_first_result_set

This is the DMV equivalent of sp_describe_first_result_set. Sample execution is as shown below:

USE AdventureWorks2012
GO
SELECT * 
FROM sys.dm_exec_describe_first_result_set(N'SELECT Employee.BusinessEntityID,
                                                    Employee.BirthDate,
                                                    Employee.Gender,
                                                    Employee.JobTitle
                                            FROM HumanResources.Employee AS Employee',
                                            NULL,
                                            0)
GO

As you may have noticed, the function takes 3 parameters which are same as that shown above for sp_describe_first_result_set. The result set is also the same.

sys.dm_exec_describe_first_result_set_for_object

Functionally equivalent to sys.dm_exec_describe_first_result_set dynamic management function, sys.dm_exec_describe_first_result_set_for_object accepts an Object Id as input. This Object Id can be that of a T-SQL stored procedure or a T-SQL trigger. If it is the ID of any other object (such as a view, table, function, or CLR procedure), an error will be specified in the error columns of the result.

The result set is same as that of sys.dm_exec_describe_first_result_set.

Please NOTE:

Since these procedures/functions return meta-data about the return result-set, one of the following will be true if the batch is executed after execution of sp_describe_first_result_set:

  1. Result in an optimization-time error
  2. Result in a run-time error (depending upon the parameters passed or the state of the server/database, or another general run-time error)
  3. Return no result set (depending upon the parameters passed)
  4. Returns a result-set conforming to the same meta-data

References:

  1. sp_describe_first_result_set – http://msdn.microsoft.com/en-us/library/ff878602.aspx
  2. sys.dm_exec_describe_first_result_set – http://msdn.microsoft.com/en-us/library/ff878258.aspx
  3. sys.dm_exec_describe_first_result_set_for_object – http://msdn.microsoft.com/en-us/library/ff878236.aspx

Until we meet next time,

Be courteous. Drive responsibly.

#0206 – SQL Server (2008 R2 & below) – SET FMTONLY – Parse, Compile & Execute a T-SQL query; return only metadata


One may encounter many situations wherein the database objects (an ad-hoc query, stored procedures, functions, etc) need to supply meta-data to the calling applications so that the format of the response can be tested without actually running the query. A real-world example is to ensure that the application is working with the correct version of the database. If the number or type of the columns returned are not as per expectations, the user can be presented with a well-formed message rather than an exception. I believe ADO uses this mechanism to make a “dry-run”.


In SQL Server 2008 R2 and below, one SET option comes in very handy in realizing this requirement. This option is the FMTONLY option.


NOTE: The FMTONLY option is marked as a deprecated feature in SQL Server 2012. I will be writing about the replacement in the immediate future.


SET FMTONLY


At execute time, if the SQL Server database engine encounters the option FMTONLY as being set to ON, no rows are processed or sent to the client. However, the query/batch is parsed (PARSEONLY), compiled (NOEXEC) and executed. Here’s a simple demo script:

USE AdventureWorks2012
GO

--Set the FMTONLY option to ON, telling the database engine
--to Parse, Compile, Execute the query, 
--and return meta-data, but not return any records
SET FMTONLY ON

SELECT '3' AS RoundNum,
       Employee.BusinessEntityID,
       Employee.BirthDate,
       Employee.Gender,
       Employee.JobTitle
FROM HumanResources.Employee AS Employee
GO

SET FMTONLY OFF

--Check for caching
SELECT '3' AS RoundNum, usecounts, cacheobjtype, objtype, text 
FROM sys.dm_exec_cached_plans 
CROSS APPLY sys.dm_exec_sql_text(plan_handle) 
WHERE usecounts > 0 AND 
        text like '%FROM HumanResources.Employee%'
    AND text NOT LIKE '%Check%'
ORDER BY usecounts DESC;
GO

Executing the query returns two result sets – first one from the actual query (indicating that the query was actually executed), and the second result set showing that the query plan was compiled.


image


The messages tab supports the observation:


image


Please NOTE:


Please do not confuse the FMTONLY feature with the following:



  1. Query result options – Discard result after query executes – this does not return meta-data back to the client/calling application
  2. OPTION (FAST n)/Table Hint: FASTFIRSTROW – this returns n number of data rows back to the client/calling application

Until we meet next time,


Be courteous. Drive responsibly.

#0205 – SQL Server – SET options – NOEXEC – Parse, Compile, but do not Execute a T-SQL query


What would you do if someone tells you to parse and compile a T-SQL query without executing it?


This could possibly be required under a situation wherein one needs to have a compiled plan available in the procedure cache before users get into a system and the server has either been restarted or has been rebuilt.


To the best of my knowledge, there is no UI element (a toolbar button, or a check-box) to achieve this. The only way I know is to use a SET option – NOEXEC.


SET NOEXEC


As discussed in a previous post, SET options allow us to change the behaviour of SQL Server for the current session with respect to handling of specific information like date and time values, locking, Query execution, transaction, ISO settings and Statistics.


Execution of a query is a two-step process and involves query compilation and subsequent execution of the compiled plan. When the NOEXEC option is set to ON, the SQL Server database engine only compiles the query, but does not execute it. Therefore, a compiled plan is produced and stored in the procedure cache (under normal circumstances).


Let’s do a simple test to confirm this.

USE AdventureWorks2012
GO
--Set the NOEXEC option to ON, telling the database engine
--to Parse and Compile the query, but not execute it
SET NOEXEC ON

SELECT '2' AS RoundNum,
       Employee.BusinessEntityID,
       Employee.BirthDate,
       Employee.Gender,
       Employee.JobTitle
FROM HumanResources.Employee AS Employee;
GO

SET NOEXEC OFF

--Check for caching
SELECT '2' AS RoundNum, usecounts, cacheobjtype, objtype, text 
FROM sys.dm_exec_cached_plans 
CROSS APPLY sys.dm_exec_sql_text(plan_handle) 
WHERE usecounts > 0 AND 
        text like '%FROM HumanResources.Employee%'
    AND text NOT LIKE '%Check%'
ORDER BY usecounts DESC;
GO

Execution of both queries succeeds, and the 2nd query (which looks for presence of a cached plan) indicates that compilation has indeed taken place and the query plan generated.


image


Here’s what I would like to know: Have you ever encountered a situation wherein you required to set NOEXEC to ON? Do leave a note in the blog comments as you go.


Until we meet next time,


Be courteous. Drive responsibly.

#0204 – SQL Server – SET options – PARSEONLY – Parse a T-SQL query/batch but do not compile or execute it


What would you do if you wanted to check whether a particular query/batch you wrote is free from any errors without using Intelli-sense and without executing or compiling the statement?


It’s a fairly simple question for anyone who has worked with SQL Server for a considerable amount of time. You would use the tiny blue check-box besides the “Execute” and “Debug” buttons on the SSMS toolbar, right?







image
Parse button on the SSMS for SQL 2012 toolbar

SET PARSEONLY


Well, if you are a keyboard-savvy developer (like me), you would use a SET option. SET options allow us to change the behaviour of SQL Server for the current session with respect to handling of specific information like date and time values, locking, Query execution, transaction, ISO settings and Statistics.


One such option is the SET PARSEONLY option, which when set to ON, parses a T-SQL query/batch for errors without executing or compiling the query/batch.


Let’s do a simple test to confirm if this indeed works or not. After parsing the query using the PARSEONLY option, we will attempt to see if a cached plan was generated for the query. If the query compiles or gets executed, an entry would exist for the cached plan.

USE AdventureWorks2012
GO

--Set PARSEONLY to ON, indicating that the query should not be compiled or executed
SET PARSEONLY ON

SELECT '1' AS RoundNum,
       Employee.BusinessEntityID,
       Employee.BirthDate,
       Employee.Gender,
       Employee.JobTitle
FROM HumanResources.Employee AS Employee;
GO

--Set PARSEONLY to OFF
SET PARSEONLY OFF

--Check for caching of the query plan. 
--If the query was compiled, an entry would be available here
SELECT '1' AS RoundNum, usecounts, cacheobjtype, objtype, text 
FROM sys.dm_exec_cached_plans 
CROSS APPLY sys.dm_exec_sql_text(plan_handle) 
WHERE usecounts > 0 AND 
        text like '%FROM HumanResources.Employee%'
    AND text NOT LIKE '%Check%'
ORDER BY usecounts DESC;
GO

Execution of both the queries succeed, but no records are returned by the 2nd query (one which returns cached plans). Checking the “Messages” tab also tells us that no records were returned back to the client, indicating that the first query was only parsed, but not compiled or executed.


image


image


Please NOTE:



  1. The SET option – PARSEONLY is set at parse time, and not at execution or run-time. Hence, please do not use this inside a stored procedure or a trigger
  2. Successful parsing of a query does not protect against:


    • Incorrect object names
    • Any logical or business-rule related errors that may exist

  3. Hence, before integrating your code changes into source control, please make sure that you unit test your queries/batches by setting PARSEONLY to OFF


Until we meet next time,


Be courteous. Drive responsibly.