Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««12

Auditing Stored Procedure calls Expand / Collapse
Author
Message
Posted Wednesday, January 11, 2012 12:51 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Tuesday, November 25, 2014 8:21 AM
Points: 191, Visits: 902
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
Post #1234309
« Prev Topic | Next Topic »

Add to briefcase ««12

Permissions Expand / Collapse