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


INFORMATION_SCHEMA.101


INFORMATION_SCHEMA.101

Author
Message
Tom Powell-334692
Tom Powell-334692
SSC-Enthusiastic
SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)

Group: General Forum Members
Points: 152 Visits: 116
Comments posted to this topic are about the item INFORMATION_SCHEMA.101

Tom Powell
http://philergia.wordpress.com/

Tony Normandale
Tony Normandale
Valued Member
Valued Member (51 reputation)Valued Member (51 reputation)Valued Member (51 reputation)Valued Member (51 reputation)Valued Member (51 reputation)Valued Member (51 reputation)Valued Member (51 reputation)Valued Member (51 reputation)

Group: General Forum Members
Points: 51 Visits: 8
I have recently put together the following script for listing table structures which people may find useful

DECLARE @Table_Name nvarchar(128)
--SELECT * FROM INFORMATION_SCHEMA.TABLES
DECLARE myCursor CURSOR
FOR SELECT [TABLE_NAME] FROM INFORMATION_SCHEMA.TABLES
WHERE [TABLE_NAME]<>'sysdiagrams'
ORDER BY [TABLE_NAME]
----
OPEN myCursor
FETCH NEXT FROM myCursor
INTO @Table_Name
WHILE (@@FETCH_STATUS=0)
BEGIN
SELECT "table_name"='['+[TABLE_NAME]+']',"ordinal_position"=-1 FROM INFORMATION_SCHEMA.TABLES
WHERE [TABLE_NAME]=@Table_Name
Union
Select
column_name+' ('+
data_type + CASE WHEN left(data_type,2)='bi'
THEN ''
WHEN data_type='datetime'
THEN ''
WHEN data_type='int'
THEN ''
WHEN character_maximum_length<0
THEN '(nomax)'
WHEN numeric_precision_radix>numeric_precision
THEN '('+convert(varchar(4),numeric_precision)+','+convert(varchar(4),numeric_scale)+')'
WHEN numeric_precision_radix<numeric_precision
THEN '('+convert(varchar(4),numeric_precision)+','+convert(varchar(4),numeric_scale)+')'
ELSE '('+convert(varchar(4),character_maximum_length)+')'
END
+ CASE WHEN is_nullable='NO'
THEN ', not null'
ELSE ', default='+ CASE WHEN column_default is null
THEN 'NULL'
ELSE column_default
END
END
+')'
,ordinal_position
From INFORMATION_SCHEMA.COLUMNS c
Where [TABLE_NAME]=@Table_Name
Order by ordinal_position,table_name

FETCH NEXT FROM myCursor
INTO @Table_Name

END
----
CLOSE myCursor
DEALLOCATE myCursor

CGSJohnson
CGSJohnson
Hall of Fame
Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)

Group: General Forum Members
Points: 3448 Visits: 1689
Thanks, Tom.
Eric M Russell
Eric M Russell
SSC-Forever
SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)

Group: General Forum Members
Points: 43129 Visits: 12018
When writing DDL deployment scripts, I try to leverage information schema views rather than system views.

-- If a named constraint exists, then drop it:
if exists (select * from information_schema.table_constraints
where table_schema = 'schema_name'
and table_name = 'table_name'
and constraint_name = 'cc_constraint_name')
begin
alter table someschemaname.sometablename
drop constraint cc_someconstraintname;
end;


-- If a column does not exist, then add it:
if not exists (select 1 from information_schema.columns
where table_schema = 'schema_name'
and table_name = 'table_name'
and column_name = 'column_name')
begin
alter table schema_name.table_name
add column_name int null;
end;


However, indexes are one example of a common database object that (as far as I know) arn't covered, so I have to fall back to using sys.sysindexes.
-- If an index does not exist, then create it:
if not exists (select * from sys.sysindexes where name = 'ix_index_name')
begin
create nonclustered index ix_index_name ...
end;




"The universe is complicated and for the most part beyond your control, but your life is only as complicated as you choose it to be."
anthony.r.lopez
anthony.r.lopez
SSC Rookie
SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)

Group: General Forum Members
Points: 29 Visits: 14
Thanks Tom, this article is very timely as I am embarking on migrating my databases over to SQLSvr2008 (from 2000) and I'm also looking for opportunities to consolidate and prune certain databases. This will help a lot, thanks again.
Anthony
John Mitchell-245523
John Mitchell-245523
SSC Guru
SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)

Group: General Forum Members
Points: 54412 Visits: 16966
A good overview of the INFORMATION_SCHEMA views, Tom, and I, like Eric, also use them where possible. For the situation you mentioned with the routine definition spanning two rows, you can use the sys.sql_modules view, since the whole definition fits on one row.

John
jpittman2
jpittman2
Grasshopper
Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)

Group: General Forum Members
Points: 17 Visits: 8
Great article. I love your final quip about being a Calvinist.
:-)

FWIW, I've developed a set of views that allow you to query for any table or view to see what other tables or views reference them. True you can get similar results using "Show Dependencies", but I've not found that that's very reliable, especially when it comes to UNIONs and Subselects. Note, however it uses substring matches, so there may be some false positives.
Attachments
04 - Dependencies views.txt (17 views, 16.00 KB)
Tom Powell-334692
Tom Powell-334692
SSC-Enthusiastic
SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)

Group: General Forum Members
Points: 152 Visits: 116
I'm glad my article is scaring out all these scripts. There's no point in reinventing the wheel.

Tom Powell
http://philergia.wordpress.com/

Trey Staker
Trey Staker
SSCommitted
SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)

Group: General Forum Members
Points: 1870 Visits: 2788
Thanks for the article. The discussion has also been nice.

---------------------------------------------------------------------
Use Full Links:
KB Article from Microsoft on how to ask a question on a Forum
Malcolm Wynden
Malcolm Wynden
SSC Veteran
SSC Veteran (286 reputation)SSC Veteran (286 reputation)SSC Veteran (286 reputation)SSC Veteran (286 reputation)SSC Veteran (286 reputation)SSC Veteran (286 reputation)SSC Veteran (286 reputation)SSC Veteran (286 reputation)

Group: General Forum Members
Points: 286 Visits: 349
Thanks Tom - I have noted that the ROUTINE_DEFINITION that SQL Server seems to be constrained only to the FIRST 4000 characters, rather than 4000 character "chunks". This makes this much less useful, as comments tend to lead off my stored procs and functions, and this gets counted in the 4000 "searchable" limit.
I go with the more robust sql_modules
SELECT OBJECT_NAME(T1.object_id)
FROM sys.sql_modules AS T1
WHERE T1.definition LIKE '%MySearchString%'
This handles the both multiple "chunks", as well as the Calvinist issue :-)
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