CREATE PROCEDURE dbo.ProcName_DEL
-- list input parameters first, then optional parameters, and finally all output parameters:
@intPKid int -- REQUIRED primary key for record to be processed
, @intProcessIND int = NULL OUTPUT -- OPTIONAL parameter for returning managed exception value
, @bitDebug bit = 0 -- OPTIONAL development flag to toggle PRINT statements on/off
AS
/*
Procedure Name: ProcName_DEL
Description: TEMPLATE
Copyright XYZ 2007, all rights reserved.
Project v01.00.01
Revision History
Name Date Reason Description
L. N. Bruno 01/01/1900 Original Initial version
*/
-- eliminate SQL Server's "done in proc" messages:
SET NOCOUNT ON
-- standard debugging/error routine variables:
DECLARE
@vcProcedureName varchar(200)
, @vcStage varchar(200)
, @vcStagePlus varchar(200)
, @intError int
-- procedure specific variables:
DECLARE
@vcMessage varchar(2000)
/*
-- FOR TESTING:
declare
@intPKid int
, @intProcessIND int
, @bitDebug bit
set @intPKid = 1
set @intProcessIND = NULL
set @bitDebug = 1 -- execute the print statements for debugging
-- END TESTING
*/
-- set default values for variables:
SET @vcProcedureName = 'ProcName_DEL'
SET @vcStage = NULL
SET @vcStagePlus = NULL
SET @intError = 0
BEGIN
-- initialize debugging:
IF @bitDebug = 1 PRINT '================================================================================'
IF @bitDebug = 1 PRINT 'Procedure ' + @vcProcedureName + ' started at ' + RTRIM(CONVERT(varchar, GETDATE(), 109)) + '.'
SET @vcStage = 'Step 1: validate primary key and perform "soft" delete'
SET @vcStagePlus = space(4) + 'Primary key: ' + RTRIM(CONVERT(varchar(5), @intPKid))
IF @bitDebug = 1 PRINT ' '
IF @bitDebug = 1 PRINT @vcStage
IF @bitDebug = 1 PRINT @vcStagePlus
IF EXISTS(SELECT PrimaryKey FROM dbo.TableName WHERE PrimaryKey = @intPKid)
BEGIN
BEGIN TRAN @vcProcedureName
SET @vcStagePlus = space(4) + 'Primary key found; performing soft delete'
IF @bitDebug = 1 PRINT @vcStagePlus
UPDATE dbo.TableName
SET SoftDeleteIND = 1
, Updated_User = ''
, Updated_Date = GETDATE()
WHERE PrimaryKey = @intPKid
SET @intError = @@ERROR
IF @intError > 0
BEGIN
ROLLBACK TRAN
SET @vcStagePlus = space(4) + 'Error in performing soft delete'
IF @bitDebug = 1 PRINT @vcStagePlus
GOTO ErrExit
END
IF @@ROWCOUNT > 1
BEGIN
ROLLBACK TRAN
SET @vcStagePlus = space(4) + 'More than one record would be affected; transaction was rolled back.'
IF @bitDebug = 1 PRINT @vcStagePlus
GOTO ErrExit
END
COMMIT TRAN @vcProcedureName
END
ELSE
BEGIN
SET @vcStagePlus = space(4) + 'Primary key not found in table.'
IF @bitDebug = 1 PRINT @vcStagePlus
SET @intProcessIND = -1 -- not found
RETURN
END
-- conclude debugging:
IF @bitDebug = 1 PRINT ' '
IF @bitDebug = 1 PRINT 'Procedure ' + @vcProcedureName + ' successfully ended at ' + RTRIM(CONVERT(varchar, GETDATE(), 109)) + '.'
IF @bitDebug = 1 PRINT '================================================================================'
-- reset SQL Server's "done in proc" messages:
SET NOCOUNT OFF
END
-- ERROR MANAGEMENT
ErrExit:
IF @intError = 0 SET @intError = @@ERROR
SET @vcMessage = 'Procedure ' + @vcProcedureName + ' failed at ' + RTRIM(CONVERT(varchar, GETDATE(), 109)) + '.'
SET @vcMessage = @vcMessage + @vcStage + @vcStagePlus
SET @vcMessage = @vcMessage + '; Error code: ' + RTRIM(CONVERT(varchar(10), @intError))
IF @intError > 0 RAISERROR(@vcMessage, 16, 1)
-- END ProcName_DEL
GO