SQL SERVER – SELECT * and Adding Column Issue in View – Limitation of the View 4

Update: Please read the summary post of all the 11 Limitations of the view SQL SERVER – The Limitations of the Views – Eleven and more…

This is very well known limitation of the View.

Once the view is created and if the basic table has any column added or removed, it is not usually reflected in the view till it is refreshed.

To test this, we will create a view where we will use SELECT * and select everything from the table. Once the view is created, we will add a column to the view. We will test that even though we have used SELECT *, the view does not retrieve the newly added column. Once we refresh the view using SP_REFRESHVIEW, it will start retrieving the newly added column.

Run the following T-SQL script in SQL Server Management Studio New Query Window:

USE AdventureWorks
GO
IF EXISTS (SELECT * FROM sys.views WHERE OBJECT_ID = OBJECT_ID(N'[dbo].[LimitView4]'))
DROP VIEW [dbo].[LimitView4]
GO
-- Create View
CREATE VIEW LimitView4
AS
SELECT
*
FROM HumanResources.Shift
GO
-- Select from original table
SELECT *
FROM HumanResources.Shift
GO
-- Select from View
SELECT *
FROM LimitView4
GO
-- Add Column to original Table
ALTER TABLE HumanResources.Shift
ADD AdditionalCol INT
GO
-- Select from original table
SELECT *
FROM HumanResources.Shift
GO
-- Select from View
SELECT *
FROM LimitView4
GO
-- Refresh the view
EXEC sp_refreshview 'LimitView4'
GO
-- Select from original table
SELECT *
FROM HumanResources.Shift
GO
-- Select from View
SELECT *
FROM LimitView4
GO
-- Clean up
ALTER TABLE HumanResources.Shift
DROP COLUMN AdditionalCol
GO

Above query will return following resultset.

The same limitation exits in the case of deleting the column as well. This is a very well-known issue with the Views. The resolutions of these issues are as follows:

  1. Refresh the views using sp_refreshview stored procedure
  2. Do not use SELECT * but use SELECT columnnames
  3. Create view with SCHEMABINDING; this way, the underlying table will not get modified.

I am enjoying writing this series of blog posts on the limitation of the views. Do let me know if there is any other limitation you would like to read on this blog.

Reference: Pinal Dave (http://blog.sqlauthority.com)

About these ads

16 thoughts on “SQL SERVER – SELECT * and Adding Column Issue in View – Limitation of the View 4

  1. Hi,

    What do you think about joining views? I think, this is bad practise. They are very hard to debag and to find issuse. However, in company that I work for, joining views is regular practise.

  2. I came across the same issue recently as well and got around it by generating the ALTER VIEW script through SSMS and re-executing it with no changes. I didn’t know about sp_refreshview. Thanks!

  3. Pinal,
    does that mean, that each time when modification is made to the table, views need to be refresh?

    There may be cases when, one doesn’t realizes or remember to refresh views.

    Do we have anyother options to avoid this kind of situations?

  4. I think you need to better emphasize the folly of using SELECT * in a view definition (or, in fact, anywhere in released code). If it were up to me writing

    CREATE VIEW v AS
    SELECT * …

    would throw an error.

    Regards
    Jamie

  5. After Removing the Additional Column Which Added By Using The ALTER Command,We Have To Refresh The
    View Again,Otherwise, It Wil Not Display The Records In The View.

    Thank You

  6. This limitation asked me in one of my interview and i could not able to answer it.

    Then i searched this limitation in your blog and i found the article related with it.

    All right now i know more about View

    Pinal you are the best

    Thanks

  7. Pingback: SQL SERVER – Interview Questions and Answers – Frequently Asked Questions – Data Warehouseing Concepts – Day 20 of 31 Journey to SQLAuthority

  8. Pingback: SQL SERVER – Weekly Series – Memory Lane – #008 « SQL Server Journey with SQL Authority

  9. Pingback: SQL SERVER – Weekly Series – Memory Lane – #047 | Journey to SQL Authority with Pinal Dave

  10. Pingback: SQL SERVER – Weekly Series – Memory Lane – #048 | Journey to SQL Authority with Pinal Dave

  11. Pingback: SQL SERVER – Weekly Series – Memory Lane – #049 | Journey to SQL Authority with Pinal Dave

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s