Bah, for the forth time in a week I encounter a star in the select-list of a view. So if no-one told you yet; when creating views, don’t do a SELECT * FROM source, it can (and in time will) hurt you badly. Let’s show by creating a table and two views based on that table;CREATE TABLE tblSource( Col1 nchar(10), Col2 nchar(10))GOCREATE VIEW vwBadASSELECT * FROM tblSourceGOCREATE VIEW vwGoodASSELECT Col1, Col2 FROM tblSourceGOINSERT tblSource (Col1, Col2) VALUES ('Column 1', 'Column 2')GO
So far, so good. Selecting from both views shows you the expected results:
SELECT 'vwGood' view_name, * FROM vwGoodGOSELECT 'vwBad' view_name, * FROM vwBadGO
Now add a column to the table, and add some data for that column;
ALTER TABLE tblSource ADD Col3 tinyintGOUPDATE tblSourceSET Col3 = 3GO
vwGood still behaves as expected, but vwBad doesn’t return ALL columns as you may have expected based on the *. Now let's see what happens if a column is removed from the table;
ALTER TABLE tblSource DROP COLUMN Col2GO
You will notice that vwGood throws an error (rightfully so, it is instructed to select from a non-existing column), but vwBad doesn’t… it pretends Col3 is Col2. Based on the data, we know better. However this might not be so obvious if based on this change the purchase price is shown as sales price due to changes in the data model and your company starts losing money.
I bet now you want to know which views contain * so you can code them properly, try this query if you're on SQL Server 2005:
SELECT v.name view_name , s.name schema_name , u.name user_name , v.create_date , v.modify_date , sc.textFROM sys.views v INNER JOIN sys.syscomments sc ON v.object_id = sc.id INNER JOIN sys.schemas s ON v.schema_id = s.schema_id INNER JOIN sys.sysusers u ON s.principal_id = u.uidWHERE sc.text LIKE '%*%'
And this one for SQL Server 2000:
SELECT so.name view_name , u.name user_name , so.crdate create_date , sc.textFROM dbo.sysobjects so INNER JOIN dbo.syscomments sc ON so.uid = sc.uid INNER JOIN dbo.sysusers u ON so.uid = u.uidWHERE sc.text LIKE '%*%' AND v.type = 'V'
And don't forget to clean up the example:
DROP VIEW vwGoodGODROP VIEW vwBadGODROP TABLE tblSourceGO