SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Auditing Stored Procedure calls


Auditing Stored Procedure calls

Author
Message
vikingDBA
vikingDBA
SSC-Addicted
SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)SSC-Addicted (418 reputation)

Group: General Forum Members
Points: 418 Visits: 929
In case this helps anyone, here is how I do in-SPROC logging. In addition to the normal stuff, I also log the input parameter values that are sent to the SPROC.




/* ========================================================================================== */
/* Example: How to log SPROC execution */
/* ========================================================================================== */
CREATE TABLE DBActivityLog
( DBActivityID int IDENTITY NOT NULL
CONSTRAINT PK_DBActivityLog_On_DBActivityID PRIMARY KEY CLUSTERED,
DBASPROC varchar(300) NULL,
DBAMessage varchar(1000) NULL,
DBAAppName varchar(150) NULL DEFAULT APP_NAME(),
DBAHost varchar(50) NULL DEFAULT HOST_NAME(),
DBAUser varchar(50) NULL DEFAULT USER,
DBADate datetime NULL DEFAULT GETDATE()
)
ON MyDatabase_data
GO
/* ========================================================================================== */
CREATE TABLE AppErrorLog
( EID int IDENTITY NOT NULL
CONSTRAINT PK_AppErrorLog_On_EID PRIMARY KEY CLUSTERED,
EDate datetime NOT NULL,
EUser varchar(50) NULL,
EMessage varchar(1000) NULL,
ESource varchar(150) NOT NULL,
ENo int NOT NULL DEFAULT 0,
ESeverity int NOT NULL DEFAULT 0,
ELineNo int NOT NULL DEFAULT 0,
EHost varchar(50) NULL
)
ON MyDatabase_data
GO
/* ========================================================================================== */
/* ========================================================================================== */
-- Example Stored Procedure using both tables created above
CREATE PROCEDURE dbo.xp_usp_Read_Account_Rec
@acctid int,
@spstat int OUTPUT,
@errmsg varchar(200) OUTPUT,
@recn int OUTPUT
AS
DECLARE @numrecs int
DECLARE @pvalue varchar(1000) --log db activity

SET NOCOUNT ON

SET @spstat = 1 -- go ahead and set to ok
SET @errmsg = '' -- go ahead and set to ok
SET @recn = 0 -- go ahead and set to ok

BEGIN TRY
--log db activity
SET @pvalue = CONVERT(varchar(100),@acctid)
INSERT INTO DBActivityLog
VALUES ('dbo.xp_usp_Read_Account_Rec',CONVERT(varchar(1000),'SPROC call - Params= ' + @pvalue),APP_NAME(),HOST_NAME(),USER,GETDATE())

--Select the desired information
SELECT AcctID,CandidateID,CandidateStatusID,AcctOpen,AcctStatusID,AcctComment,CurrRec,LCHost,LCUser,LCDate
FROM Account
WHERE AcctID=@acctid

SET @numrecs = @@rowcount

if @numrecs=0
BEGIN
SET @spstat = -1
SET @errmsg = 'No record selected'
SET @recn = 0
END

RETURN @spstat
END TRY
BEGIN CATCH
DECLARE @ErrorNo int,
@Severity int,
@State int,
@LineNo int,
@errmessage varchar(1000)
SELECT @ErrorNo = ERROR_NUMBER(),
@Severity = ERROR_SEVERITY(),
@State = ERROR_STATE(),
@LineNo = ERROR_LINE(),
@errmessage = ERROR_MESSAGE()

SET @errmsg = CONVERT(varchar(200), @errmessage)
SET @spstat = 0

INSERT INTO AppErrorLog
VALUES (GETDATE(), USER, @errmessage, 'dbo.xp_usp_Read_Account_Rec', @ErrorNo, @Severity, @LineNo, HOST_NAME())
END CATCH
GO
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search