Blog Post

My view isn’t reflecting changes I’ve made to the underlying tables.

,

Problem: You’ve added columns to the base table of one of your views, but the view isn’t reflecting the change.

Over the years I’ve seen lot’s of views created similar to this one.

CREATE VIEW vw_TableView AS
SELECT * FROM TableName

Generally the argument is that if I put “SELECT *” rather than an explicit field list, then when my table changes so will my view. Unfortunately it doesn’t work that way.

Let’s try an example.

Create a test table and populate it with some data.

 CREATE TABLE TableName (Column1 varchar(10))
GO
INSERT INTO TableName VALUES ('abcdefg')
INSERT INTO TableName VALUES ('hij')
INSERT INTO TableName VALUES ('klmnop')
INSERT INTO TableName VALUES ('qrstuvwxy')
INSERT INTO TableName VALUES ('zabcde')
INSERT INTO TableName VALUES ('123456')
GO

Create a test view.

 CREATE VIEW vw_TableView AS
SELECT * FROM TableName
GO

Test the view to make sure we are getting the data we expect.

 SELECT * FROM vw_TableView
GO

So far so good. The output is exactly what we expected. Now let’s add a column to the table and populate it.

 ALTER TABLE TableName ADD Column2 INT
GO
UPDATE TableName SET Column2 = 3
GO

And try out the view again.

 SELECT * FROM vw_TableView
GO
Column1
abcdefg
hij
klmnop
qrstuvwxy
zabcde
123456

Now wait just a minute. The output I’m getting looks exactly like it did before I added Column2. All I’m seeing is Column1. Now the first thing I do when debugging something like this is make sure the view should in fact be pulling the new column. So:

EXEC sp_helptext vw_TableView
 Text
---------------------------------------------------------------
CREATE VIEW vw_TableView AS
SELECT * FROM TableName

Ok, so the code still looks correct. So why aren’t we pulling all of the columns even though we are using a *? From what I understand the metadata for the view is not automatically updated when the tables are modified.

The fix is to either drop and re-create or alter the view or to use the sp_refreshview stored procedure. Sp_refreshview has the combined benefit of being the simplest method and not messing up any explicit permissions on the view caused by dropping it.

 EXEC sp_RefreshView vw_TableView
GO

And test the view again.

 SELECT * FROM vw_TableView
GO
Column1Column2
abcdefg3
hij3
klmnop3
qrstuvwxy3
zabcde3
1234563

And now we have the correct number of columns for our view.

Next let’s try going the other way. We remove a column from the table.

 ALTER TABLE TableName DROP Column2
GO

And we try querying the view again. (I’m hoping no one expects it to work correctly.)

 SELECT * FROM vw_TableView
GO

This time we get an error.

 Msg 4502, Level 16, State 1, Line 1
View or function 'vw_TableView' has more column names specified than columns defined.

If we again run sp_refreshview then the view will once again show the expected data.

 EXEC sp_RefreshView vw_TableView
GO
SELECT * FROM vw_TableView
GO
Column1
abcdefg
hij
klmnop
qrstuvwxy
zabcde
123456

And last but not least some cleanup code.

DROP VIEW vw_TableView
DROP TABLE TableName
GO

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating