How to create a simple ETL/stored procedure error capturing database (schema model, SQL code and implementation) – Part 2
PART 1 of this series I analysed the execution error tracking database schema as well as the code for ‘scraping’ SQL Server metadata in order to populate the database tables with instance, database, schema and objects-specific information. In this part I will briefly describe SQL code modifications which are applied the original stored procedure (see PART 1) to customize it in order to handle metadata changes as well as the actual implementation and error-logging mechanism during package/stored procedure execution. Also, all the code and any additional files presented in this and previous part can be downloaded from my OneDrive folder HERE.
InBefore I get into the nuts and bolts on how to log into LogSSISErrors_Error table, which in this case will form the base for all errors entries, let create a sample database, schema, table and stored procedure containing an error-invoking code i.e. executing division by 0. This stored procedure, which will later be appended with additional error-handling code it in order to capture and log execution error(s) through TRY/CATCH T-SQL, will be used as the basis for demonstrating error capturing mechanism.
USE master IF EXISTS ( SELECT TOP 1 * FROM sys.databases WHERE name = 'TestDB' ) DROP DATABASE TestDB CREATE DATABASE TestDB GO USE TestDB EXEC sp_executesql N'CREATE SCHEMA dummyschema;'; GO CREATE TABLE dummyschema.DummyTable ( ID INT IDENTITY(1, 1) , Column1 VARCHAR(56) , Column2 VARCHAR(56) , Column3 VARCHAR(56) ) INSERT INTO dummyschema.DummyTable ( Column1 , Column2 , Column3 ) SELECT 'dummy value1' , 'dummy value1' , 'dummy value1' UNION ALL SELECT 'dummy value1' , 'dummy value1' , 'dummy value1' UNION ALL SELECT 'dummy value1' , 'dummy value1' , 'dummy value1' GO CREATE PROCEDURE dummyschema.usp_DummySP ( @ExecutionInstanceGUID UNIQUEIDENTIFIER , @PackageName NVARCHAR(256) ) AS BEGIN INSERT INTO TestDB.dummyschema.DummyTable ( Column1 ) SELECT 1 / 0 END
As this database is supposed to be working mainly in conjunction with an SSIS package (standalone stored procedure execution error capture is also fine but in this case the SSIS component would have to be omitted and replaced with a place-holder value), I have also created a sample package used primarily to trigger stored procedure execution, with a couple of system variables capturing package execution instance GUID identifier and package name metadata. This package needs to be saved somewhere on the C:\ drive for the metadata updating stored procedure to find the relevant info and populate LogSSISErrors_Package table accordingly.
Most of that code from PART 1 is also applicable to maintaining the error tracking database by means of modifying INSERT statements into MERGE statements, thus allowing for applying changes to already existing data and inserting new records. The core difference is that in PART 1 all AdminSQL database objects required to be (re)created before we could proceed with SQL Server instance metadata analysis and capture thus making its execution only applicable to a new environment, where the database needed to be rebuilt from scratch. Once SQLAdmin database has been created and initially populated with the code from PART 1, any subsequent execution should account for updates and new data inserts only which are implemented by means of subtle changes to the stored procedure code, mainly replacing INSERTS with MERGE T-SQL. Below is a couple of examples where the code from PART 1 stored procedure was replaced with MERGE SQL statements with the complete code available for download from HERE.
------------------------------------------------------------------------------------------------------- --Update LogSSISErrors_Schema table ------------------------------------------------------------------------------------------------------- MERGE INTO AdminDBA.dbo.LogSSISErrors_Schema AS t USING ( SELECT DISTINCT db.ID AS ID , meta.SchemaID AS SchemaID , meta.SchemaName AS SchemaName , meta.SchemaOwner AS SchemaOwner , 1 AS CurrentlyUsed FROM @EnumDBMeta meta JOIN AdminDBA.dbo.LogSSISErrors_DB db ON meta.DBName = db.DBName WHERE db.CurrentlyUsed = 1 ) s ON ( t.SchemaName = s.SchemaName AND s.ID = t.FKDBID ) WHEN MATCHED THEN UPDATE SET [SchemaID] = s.[SchemaID] , [SchemaName] = s.[SchemaName] , [SchemaOwner] = s.[SchemaOwner] , [CurrentlyUsed] = s.[CurrentlyUsed] WHEN NOT MATCHED THEN INSERT ( [FKDBID] , [SchemaID] , [SchemaName] , [SchemaOwner] , [CurrentlyUsed] ) VALUES ( s.[ID] , s.[SchemaID] , s.[SchemaName] , s.[SchemaOwner] , s.[CurrentlyUsed] ) WHEN NOT MATCHED BY SOURCE THEN UPDATE SET [CurrentlyUsed] = 0; ------------------------------------------------------------------------------------------------------- --Update LogSSISErrors_Process table ------------------------------------------------------------------------------------------------------- MERGE INTO AdminDBA.dbo.LogSSISErrors_Process AS t USING ( SELECT DISTINCT meta.ProcessObjectID , meta.ProcessObjectName , sch.ID , 1 AS CurrentlyUsed FROM @EnumDBMeta meta JOIN AdminDBA.dbo.LogSSISErrors_Schema AS sch ON sch.SchemaName = meta.SchemaName AND meta.ProcessObjectSchemaID = sch.SchemaID JOIN AdminDBA.dbo.LogSSISErrors_DB db ON meta.DBName = db.DBName AND sch.FKDBID = db.ID WHERE sch.CurrentlyUsed = 1 AND db.CurrentlyUsed = 1 AND ProcessObjectType IN ( 'SQL Stored Procedure', 'Aggregate Function', 'SQL DML Trigger', 'Assembly DML Trigger', 'Extended Stored Procedure', 'Assembly Stored Procedure', 'Replication Filter Procedure', 'Assembly Scalar Function', 'SQL Scalar Function' ) ) s ON ( t.ProcessName = s.ProcessObjectName AND s.ID = t.FKSchemaID ) WHEN MATCHED THEN UPDATE SET [ProcessID] = s.ProcessObjectID , [ProcessName] = s.ProcessObjectName , [CurrentlyUsed] = s.[CurrentlyUsed] WHEN NOT MATCHED THEN INSERT ( [ProcessID] , [ProcessName] , [FKSchemaID] , [CurrentlyUsed] ) VALUES ( s.ProcessObjectID , s.ProcessObjectName , s.ID , s.[CurrentlyUsed] ) WHEN NOT MATCHED BY SOURCE THEN UPDATE SET [CurrentlyUsed] = 0;
Upon execution of the modified stored procedure from PART 1, the code should pick up our new database, schema, table and stored procedure which in turn should be reflected in AdminDBA database tables’ entries i.e. LogSSISErrors_Package, LogSSISErrors_DB, LogSSISErrors_Schema, LogSSISErrors_Object, and LogSSISErrors_Process tables as per the image below.
When trying to execute the package, an error message is thrown due to T-SQL in usp_DummySP stored procedure attempting to divide by zero, which is in accordance with our expectations. The stored procedure does not contain error handling code therefore division by zero operation is handled by halting execution and returning the error message back to Execution Results view as per below. Also, the package invoking the stored procedure needs to be saved
Now let’s alter the dummyschema.usp_DummySP stored procedure’s code to allow error capture and handling capabilities. By default SQL Server has a number of system functions available to troubleshoot execution flow and expose error details. In combination with SSIS package system parameters i.e. execution instance GUID and package name, we can capture and log those details in LogSSISErrors_Error table, referencing other tables which provide other metadata details for richer analysis.
The following ALTER SQL statements implements TRY/CATCH SQL Server error handling capabilities and allows for logging execution issues e.g. dividing by zero in the highlighted SELECT statement section.
USE [TestDB] GO ALTER PROCEDURE [dummyschema].[usp_DummySP] ( @ExecutionInstanceGUID UNIQUEIDENTIFIER , @PackageName NVARCHAR(256) ) AS BEGIN BEGIN TRY BEGIN TRANSACTION INSERT INTO TestDB.dummyschema.DummyTable ( Column1 ) SELECT 1 / 0 COMMIT TRANSACTION END TRY BEGIN CATCH ROLLBACK TRANSACTION; WITH TempErr ( [ErrorNumber], [ErrorSeverity], [ErrorState], [ErrorLine], [ErrorMessage], [ErrorDateTime], [LoginName], [UserName], PackageName, [ObjectID], [ProcessID], [ExecutionInstanceGUID], [DBName] ) AS ( SELECT ERROR_NUMBER() AS ErrorNumber , ERROR_SEVERITY() AS ErrorSeverity , ERROR_STATE() AS ErrorState , ERROR_LINE() AS ErrorLine , ERROR_MESSAGE() AS ErrorMessage , SYSDATETIME() AS ErrorDateTime , SYSTEM_USER AS LoginName , USER_NAME() AS UserName , @PackageName , OBJECT_ID('TestDB.dummyschema.DummyTable') AS ObjectID , ( SELECT a.objectid FROM sys.dm_exec_requests r CROSS APPLY sys.dm_exec_sql_text(r.sql_handle) a WHERE session_id = @@spid ) AS ProcessID , @ExecutionInstanceGUID AS ExecutionInstanceGUID , DB_NAME() AS DatabaseName ) INSERT INTO AdminDBA.dbo.LogSSISErrors_Error ( [ErrorNumber] , [ErrorSeverity] , [ErrorState] , [ErrorLine] , [ErrorMessage] , [ErrorDateTime] , [FKLoginID] , [FKUserID] , [FKPackageID] , [FKObjectID] , [FKProcessID] , [ExecutionInstanceGUID] ) SELECT ErrorNumber = COALESCE(err.ErrorNumber, -1) , ErrorSeverity = COALESCE(err.[ErrorSeverity], -1) , ErrorState = COALESCE(err.[ErrorState], -1) , ErrorLine = COALESCE(err.[ErrorLine], -1) , ErrorMessage = COALESCE(err.[ErrorMessage], 'Unknown') , ErrorDateTime = ErrorDateTime , FKLoginID = src_login.ID , FKUserID = src_user.ID , [FKPackageID] = src_package.ID , [FKObjectID] = src_object.ID , [FKProcessID] = src_process.ID , [ExecutionInstanceGUID] = err.ExecutionInstanceGUID FROM TempErr err LEFT JOIN AdminDBA.dbo.LogSSISErrors_Login src_login ON err.LoginName = src_login.LoginName LEFT JOIN AdminDBA.dbo.LogSSISErrors_User src_user ON err.UserName = src_user.UserName AND src_user.FKDBID = (SELECT ID FROM AdminDBA.dbo.LogSSISErrors_DB db WHERE db.DBName = err.DBName) LEFT JOIN AdminDBA.dbo.LogSSISErrors_Package src_package ON err.PackageName = (LEFT(src_package.PackageName, CHARINDEX('.', src_package.PackageName) - 1)) LEFT JOIN AdminDBA.dbo.LogSSISErrors_Object src_object ON err.ObjectID = src_object.ObjectID LEFT JOIN AdminDBA.dbo.LogSSISErrors_Process src_process ON err.ProcessID = src_process.ProcessID --WHERE --src_login.CurrentlyUsed = 1 AND --src_user.CurrentlyUsed = 1 AND --src_package.CurrentlyUsed = 1 AND --src_object.CurrentlyUsed = 1 AND --src_process.CurrentlyUsed = 1 END CATCH END
Once altered, the stored procedure executed through the package will write into the table if BEGIN CATCH/END CATCH statement is invoked as per image below.
Now that error details have been inserted into our AdminDBA database table, we can query the data across all related tables if more comprehensive view is required e.g. schema, database etc. Below sample query sets up a view which can be used through a reporting platform of choice to quickly identify transactional SSIS execution issues or perform a quick analysis on errors and their related objects, schemas, processes, packages etc.
CREATE VIEW [dbo].[vw_LogSSISErrors_CoreData] AS SELECT dbo.LogSSISErrors_Error.ID AS Error_ID , dbo.LogSSISErrors_Error.ErrorNumber , dbo.LogSSISErrors_Error.ErrorSeverity , dbo.LogSSISErrors_Error.ErrorState , dbo.LogSSISErrors_Error.ErrorLine , dbo.LogSSISErrors_Error.ErrorMessage , dbo.LogSSISErrors_Error.ErrorDateTime , dbo.LogSSISErrors_Object.ObjectName , dbo.LogSSISErrors_Object.ObjectType , dbo.LogSSISErrors_Object.ObjectDescription , dbo.LogSSISErrors_Schema.SchemaName AS ObjectSchemaName , dbo.LogSSISErrors_Process.ProcessName , LogSSISErrors_Schema_1.SchemaName AS ProcessSchemaName , dbo.LogSSISErrors_Package.PackageName , dbo.LogSSISErrors_User.UserName , dbo.LogSSISErrors_Login.LoginName , dbo.LogSSISErrors_DB.DBName , dbo.LogSSISErrors_Instance.InstanceName FROM dbo.LogSSISErrors_Error INNER JOIN dbo.LogSSISErrors_Object ON dbo.LogSSISErrors_Error.FKObjectID = dbo.LogSSISErrors_Object.ID INNER JOIN dbo.LogSSISErrors_Schema ON dbo.LogSSISErrors_Object.FKSchemaID = dbo.LogSSISErrors_Schema.ID INNER JOIN dbo.LogSSISErrors_DB ON dbo.LogSSISErrors_Schema.FKDBID = dbo.LogSSISErrors_DB.ID INNER JOIN dbo.LogSSISErrors_Instance ON dbo.LogSSISErrors_DB.FKInstanceID = dbo.LogSSISErrors_Instance.ID INNER JOIN dbo.LogSSISErrors_Package ON dbo.LogSSISErrors_Error.FKPackageID = dbo.LogSSISErrors_Package.ID INNER JOIN dbo.LogSSISErrors_Process ON dbo.LogSSISErrors_Error.FKProcessID = dbo.LogSSISErrors_Process.ID INNER JOIN dbo.LogSSISErrors_User ON dbo.LogSSISErrors_Error.FKUserID = dbo.LogSSISErrors_User.ID AND dbo.LogSSISErrors_DB.ID = dbo.LogSSISErrors_User.FKDBID INNER JOIN dbo.LogSSISErrors_Schema AS LogSSISErrors_Schema_1 ON dbo.LogSSISErrors_DB.ID = LogSSISErrors_Schema_1.FKDBID AND dbo.LogSSISErrors_Process.FKSchemaID = LogSSISErrors_Schema_1.ID INNER JOIN dbo.LogSSISErrors_Login ON dbo.LogSSISErrors_Error.FKLoginID = dbo.LogSSISErrors_Login.ID;
Based on the output of this code, we can set up a simple dashboard (Tableau in this case) to provide us with some core metrics on the ETL issues that require addressing at a glance (click on image to enlarge).
You can also download all the code samples, SSIS package solution files and database schema model (saved in a format compatible with Navicat Data Modeler database design tool) from my OneDrive folder HERE.
http://scuttle.org/bookmarks.php/pass?action=addThis entry was posted on Friday, November 7th, 2014 at 6:59 am and is filed under How To's, SQL. You can follow any responses to this entry through the RSS 2.0 feed. You can leave a response, or trackback from your own site.
admin December 10th, 2017 at 6:03 am
Hi Ed
Sorry but I don’t have any samples of actual SSIS packages handy to demonstrate this functionality. However, the actual implementation is quite straightforward i.e. for any transaction to be logged in the event of an error into AdminDBA database all you need to do is implement the BEGIN TRY…END TRY, BEGIN CATCH…END CATCH scenario, where the BEGIN CATCH…END CATCH section includes the INSERT into AdminDBA snippet of SQL. You will notice that the [dummyschema].[usp_DummySP] stored proc from this post includes division by 0 scenario which will obviously raise an error. All there’s left to do is to catch this error with all its metadata and populate AdminDBA.dbo.LogSSISErrors_Error table.
Hope that helps….
Cheers,
Martin