SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Views and Dependencies


Views and Dependencies

Author
Message
DB_Newbie2007
DB_Newbie2007
SSCrazy
SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)

Group: General Forum Members
Points: 2186 Visits: 1363
Comments posted to this topic are about the item Views and Dependencies

Argue for your limitations, and sure enough they're yours (Richard Bach, Illusions)
Andrew Diniz
Andrew Diniz
SSC Eights!
SSC Eights! (944 reputation)SSC Eights! (944 reputation)SSC Eights! (944 reputation)SSC Eights! (944 reputation)SSC Eights! (944 reputation)SSC Eights! (944 reputation)SSC Eights! (944 reputation)SSC Eights! (944 reputation)

Group: General Forum Members
Points: 944 Visits: 293
It occurs to me that our organization and developers need a better method to monitor modifications on specific objects, either DDL or DML, when then might affect "custom" or "one off" objects.


In the (unlikely) event that you're interested only in the downstream impact of changes which do not transcend your SQL database, the following may be of some use to you:

SELECT 
referencing_schema_name,
referencing_entity_name,
referencing_id,
referencing_class_desc,
is_caller_dependent
FROM sys.dm_sql_referencing_entities ('<object_name>', 'OBJECT');
GO


Bear in mind that impact analysis is a fundamental part of maintenance and Change Control and needs buy in from everyone to be effective. The work and effort involved in achieving a good mechanism is typically substantial (and costly) so needs to be balanced against the benefits of implementing it. Obviously the above snippet will not highlight the impact to items outside your database(s) so, if that constitutes a significant portion of your solution, you should probably start thinking about a lineage-impact model.
btaylor 78431
btaylor 78431
SSC Rookie
SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)

Group: General Forum Members
Points: 41 Visits: 18
I guess this is another example of why we have recommended for years not to use the syntax SELECT *
Peter H
Peter H
SSC Rookie
SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)

Group: General Forum Members
Points: 35 Visits: 62
For those who are looking for an easier way out, I put together this sql that (hopefully) will identify the views that are older than the last table modify date, and call for only them to be refreshed. I also added the schema name, because not everything is always "DBO". Someone could wrap this in a cursor and execute directly, say every night, or after each prod release, to ensure that no views were missed:

SELECT DISTINCT 'EXEC sp_refreshview ''' + OBJECT_SCHEMA_NAME(v.object_id) + '.' + v.name + ''''
--, reference=OBJECT_SCHEMA_NAME(sed.referenced_major_id) + '.' + OBJECT_NAME(sed.referenced_major_id)
--, t.modify_date, v.modify_date,*
FROM sys.objects v
INNER JOIN sys.sql_dependencies sed ON sed.object_id = v.object_id
INNER JOIN sys.objects t ON t.object_id = sed.referenced_major_id
WHERE v.type = 'V' --AND OBJECT_NAME(sed.referenced_major_id) LIKE 'MyTable%'
and t.modify_date >= v.modify_date
order by 1


timothyawiseman
timothyawiseman
SSCarpal Tunnel
SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)

Group: General Forum Members
Points: 4160 Visits: 920
Thank you for posting the article.

I would point out that it is generally advisable to avoid relying on the order of the columns in the base table. When the order matters, specify the order you want the columns to appear in. When the order will matter frequently (and in a consistent way), hide it behind a view that specifies the columns and their order.

Also, I would generally advise against using select * for anything other than probing an unfamiliar table. If you want to avoid the typing, there are several refactoring tools that integrate into SSMS that will expand a * for you.

---
Timothy A Wiseman
SQL Blog: http://timothyawiseman.wordpress.com/
Marcia J
Marcia J
SSCrazy
SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)

Group: General Forum Members
Points: 2469 Visits: 2024
Peter H, thanks for the SQL.

One thing I was wondering about is why you have the "order by 1" phrase.
Peter H
Peter H
SSC Rookie
SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)

Group: General Forum Members
Points: 35 Visits: 62
Review by object name is easier, so order by "object name". (Order by 1 means order by the first column returned).
Marcia J
Marcia J
SSCrazy
SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)

Group: General Forum Members
Points: 2469 Visits: 2024
Peter H (7/10/2012)
Review by object name is easier, so order by "object name". (Order by 1 means order by the first column returned).


Duh, I knew that. Guess my brain went to sleep. :-)
Thanks for your patience.
DBA328
DBA328
SSCommitted
SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)

Group: General Forum Members
Points: 1968 Visits: 1123
Thank you for posting the article.I have encountered a problem before. Changed the base table column data type, but the view didn't changed accordingly. So need to manually refresh the view. This is inconvenient, i was wondering why SQL Server didn't automatically update the metadata?

[li][/li]
e-ghetto
e-ghetto
Old Hand
Old Hand (376 reputation)Old Hand (376 reputation)Old Hand (376 reputation)Old Hand (376 reputation)Old Hand (376 reputation)Old Hand (376 reputation)Old Hand (376 reputation)Old Hand (376 reputation)

Group: General Forum Members
Points: 376 Visits: 248
By the way, please don't use date literals like this:

'MM/DD/YY'



This might will not work on system which use other language settings (or datetime settings) than english.

Please always use the ISO literals like this instead:
'YYYYMMDD'


They do work. Always: http://www.karaszi.com/SQLServer/info_datetime.asp
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum







































































































































































SQLServerCentral


Search