Testing for Broken Views


We recently found a view in our warehouse which had only been created for demonstration purposes but the underlying tables had changed over time.  The view was broken and, of course, someone found it.  This necessitated a remediation which would identify broken views and create a record of the issue.  Ideally, there would never be broken views if this process was in place so we could also create a record showing how few issues we have had.  

At first, I thought of creating a SQL Agent job which would query the view and fail when the view was not working. But this seemed like a lot of work as views got added over time.  So, something more flexible was called for.

I wanted to create a procedure that would test all of the views in a database and record the relevant data if the view broke.  I created a procedure with a try-catch block and selected the top(1) record from the views and when there was a failure the catch block would insert the record into a table.  This would have been pretty awesome, especially since the new STRING_AGG function in SQL 2017 makes dynamic SQL much easier to write.  But there was a problem, the view would fail but the catch block code never executed.  It turns out that broken views don't rise to the necessary level to warrant a catch.  It turns out the failed stored procedures do rise to the correct error level so the code below uses the procedure sp_refreshView.  I included the database creation, the table creation, and the stored procedure.


/**Check if the metadata_db exists and create it if not. **/

IF NOT EXISTS(SELECT name from master.dbo.sysdatabases where name = 'MetaData_DB')
CREATE Database MetaData_DB;

/** Create the Broken View table **/
USE [Metadata_DB]
GO
CREATE TABLE [dbo].[BrokenViews](
[Database_Name] [nchar](50) NULL,
[Schema_Name] [nchar](50) NULL,
[Table_Name] [nchar](100) NULL,
[Date_Broken] [date] NULL
GO


/** Create the procedure which will test views and if the view is broken add a record to the brokenViews table **/

USE <database name>
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
Create PROCEDURE [dbo].[TestViews]
  AS
       BEGIN
       DECLARE @SQL as nvarchar(max)
       SELECT @SQL = STRING_AGG(' Begin Try  exec sp_refreshview  ' + '''' + SCHEMA_NAME(schema_ID) + '.' + name + '''' + 
  ' END TRY BEGIN CATCH INSERT INTO  Metadata_DB.dbo.BrokenViews VALUES( ' + '''' + DB_NAME() + '''' + ', ' + '''' + SCHEMA_NAME(schema_ID) + '''' + ', '  + '''' + name + '''' + ', ' + '''' + CAST(CAST(GETDATE() AS DATE) AS VARCHAR) + '''' + ') END CATCH' , ';') 
  FROM sys.objects
  WHERE type = 'v'
  EXEC sp_executeSQL @SQL
  END




Popular posts from this blog

Power BI Report Server: "An Error Has Occurred" or Power BI Report Server: "My Power BI Report is Coming up Blank" or Power BI Report Server: "401 and 403” Errors From Nowhere

SQL SERVER 2017: STRING_AGG

Dynamic Label Positions With SSRS