Blog Post

DBCC INPUTBUFFER vs fn_get_sql

,

Someone asked a question in the forums the other day and I realized it would make a pretty decent blog post to explain the differences in functionality between these two and provide some code for working with them.

Differences

  • fn_get_sql returns the last *statement* executed, where as DBCC INPUTBUFFER returns the first statement in the batch.  See the example below for a better idea of what that means.
  • fn_get_sql returns a TEXT field containing the statement that ran, DBCC INPUTBUFFER returns only a varchar(255).  This is important as you often won't get the full line here... and unfortunately there's not a lot you can do about that.  To my knowledge, DBCC INPUTBUFFER is still your only means of getting the first statement in the batch, however it returns an nvarchar(4000) in 2005/2008.
  • fn_get_sql requires a SQL_Handle binary type passed in which has to be pulled out of the sysprocesses table, DBCC INPUTBUFFER only requires the SPID as a parameter.
  • fn_get_sql will return the actual creation text for an SP(or trigger, etc.) that is executing instead of all the name of the object with the parameters that DBCC INPUTBUFFER returns.

Note that fn_get_sql is available in SQL 2000 if you have sp3 and above.  You may actually have it with SP2 as well if you have the correct hotfix applied.  An easy way to tell if it will work on your system is to do a simple SELECT sql_handle FROM sysprocesses.  If that works, so will fn_get_sql.  If it doesn't, you need to patch.   There are a couple other specifics about fn_get_sql that are mentioned in the article linked at the bottom by Andrew Novick.

Sample Code

Here is some sample code for working with these:

[Edit: Fixed Code]

--- Change eventinfo to nvarchar(4000) for sql 2005 and 2008
CREATE TABLE #B(eventtype nvarchar(30), parameters int, eventinfo nvarchar(255))
INSERT INTO #B(EventType, Parameters, EventInfo)
EXEC ('dbcc inputbuffer (' + @@spid + ') with no_infomsgs')

DECLARE @handle varbinary(64)
SELECT @handle = MAX(sql_handle) FROM master..sysprocesses WHERE spid = @@SPID

SELECT * FROM ::fn_get_sql(@handle)
-- OR --
CREATE TABLE #C(dbid smallint, objectid int, number smallint, encrypted bit, [text] text)
INSERT INTO #C(DBID, ObjectID, Number, Encrypted, [Text])
SELECT * FROM ::fn_get_sql(@Handle)

Additional Links:

Andrew Novick: Find out what they’re doing with fn_get_sql 
BOL: sys.dm_exec_sql_text
BOL: fn_get_sql
BOL: DBCC INPUTBUFFER: 2008 | 2005 | 2000

 

Examples:

Here are a couple examples that show some of the differences between the two in action.

[Edit] Updated to work in 2K, this gave implicit conversion failures before.

use tempdb
GO

CREATE PROCEDURE Proc1(
@invar varchar(100)
)
AS

SET NOCOUNT ON

PRINT 'Proc 1 Executing'
DECLARE @fgs nvarchar(4000),
@handle varbinary(64),
@dbib nvarchar(4000)
SELECT @handle = MAX(sql_handle) FROM master..sysprocesses WHERE spid = @@SPID

CREATE TABLE #A(eventtype nvarchar(30), parameters int, eventinfo nvarchar(4000))
INSERT INTO #A(EventType, Parameters, EventInfo)
EXEC ('dbcc inputbuffer (' + @@spid + ') with no_infomsgs')

select @fgs = CONVERT(nvarchar(4000),SUBSTRING([Text],1,4000)) from ::fn_get_sql(@handle)
select @dbib = eventinfo from #A
PRINT 'fn_get_sql'
PRINT '---------------------'
PRINT @FGS
PRINT 'DBCC INPUTBUFFER:'
PRINT '---------------------'
PRINT @dbib

EXEC Proc2 'Executing Second Proc'

GO

CREATE PROCEDURE Proc2(
@invar varchar(100)
)
AS

SET NOCOUNT ON

PRINT 'Proc 2 Executing'
DECLARE @fgs nvarchar(4000),
@handle varbinary(64),
@dbib nvarchar(4000)
SELECT @handle = MAX(sql_handle) FROM master..sysprocesses WHERE spid = @@SPID

CREATE TABLE #B(eventtype nvarchar(30), parameters int, eventinfo nvarchar(4000))
INSERT INTO #B(EventType, Parameters, EventInfo)
EXEC ('dbcc inputbuffer (' + @@spid + ') with no_infomsgs')

select @fgs = CONVERT(nvarchar(4000),SUBSTRING([Text],1,4000)) from ::fn_get_sql(@handle)
select @dbib = eventinfo from #B
PRINT 'fn_get_sql'
PRINT '---------------------'
PRINT @FGS
PRINT 'DBCC INPUTBUFFER:'
PRINT '---------------------'
PRINT @dbib
EXEC Proc3 'Executing Third Proc'
GO

CREATE PROCEDURE Proc3(
@invar varchar(100)
)
AS

SET NOCOUNT ON
PRINT 'Proc 3 Executing'
DECLARE @fgs nvarchar(4000),
@handle varbinary(64),
@dbib nvarchar(4000)
SELECT @handle = MAX(sql_handle) FROM master..sysprocesses WHERE spid = @@SPID

CREATE TABLE #C(eventtype nvarchar(30), parameters int, eventinfo nvarchar(4000))
INSERT INTO #C(EventType, Parameters, EventInfo)
EXEC ('dbcc inputbuffer (' + @@spid + ') with no_infomsgs')

select @fgs = CONVERT(nvarchar(4000),SUBSTRING([Text],1,4000)) from ::fn_get_sql(@handle)
select @dbib = eventinfo from #C
PRINT 'fn_get_sql'
PRINT '---------------------'
PRINT @FGS
PRINT 'DBCC INPUTBUFFER:'
PRINT '---------------------'
PRINT @dbib
GO

EXEC Proc1 'Executing Proc 1'
GO

DROP PROCEDURE Proc1
DROP PROCEDURE Proc2
DROP PROCEDURE Proc3
GO

---- Example 2 -----
PRINT '------------------------------- Example 2 ---------------------------------------'
GO

CREATE TABLE A(
aval int)
GO
CREATE TRIGGER Atrig ON A
FOR INSERT
AS
SET NOCOUNT ON
DECLARE @fgs nvarchar(4000),
@handle varbinary(64),
@dbib nvarchar(4000)
SELECT @handle = MAX(sql_handle) FROM master..sysprocesses WHERE spid = @@SPID

CREATE TABLE #C(eventtype nvarchar(30), parameters int, eventinfo nvarchar(4000))
INSERT INTO #C(EventType, Parameters, EventInfo)
EXEC ('dbcc inputbuffer (' + @@spid + ') with no_infomsgs')

select @fgs = CONVERT(nvarchar(4000),SUBSTRING([Text],1,4000)) from ::fn_get_sql(@handle)
select @dbib = eventinfo from #C
PRINT 'fn_get_sql'
PRINT '---------------------'
PRINT @FGS
PRINT 'DBCC INPUTBUFFER:'
PRINT '---------------------'
PRINT @dbib
GO

INSERT INTO A(aval) SELECT 123456

GO
DROP TABLE A
GO

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating