Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Get the defination of all table type in database


Get the defination of all table type in database

Author
Message
Mitesh Oswal
Mitesh Oswal
SSC Eights!
SSC Eights! (830 reputation)SSC Eights! (830 reputation)SSC Eights! (830 reputation)SSC Eights! (830 reputation)SSC Eights! (830 reputation)SSC Eights! (830 reputation)SSC Eights! (830 reputation)SSC Eights! (830 reputation)

Group: General Forum Members
Points: 830 Visits: 653
Comments posted to this topic are about the item Get the defination of all table type in database

Regards,
Mitesh OSwal
+918698619998
thood1
thood1
Forum Newbie
Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)

Group: General Forum Members
Points: 7 Visits: 44
Mitesh,

This is the only result I received, and then only against the msdb database:

IF EXISTS(SELECT TOP 1 NULL FROM sys.systypes where Name = 'syspolicy_target_filters_type')
DROP TYPE syspolicy_target_filters_type;


CREATE TYPE syspolicy_target_filters_type AS TABLE
(target_filter_id int
,policy_id int
,type sysname
,filter nvarchar (-1)
,type_skeleton sysname
)

Did I miss something or did you omit a more complete discussion on how to setup and run this script?
Mitesh Oswal
Mitesh Oswal
SSC Eights!
SSC Eights! (830 reputation)SSC Eights! (830 reputation)SSC Eights! (830 reputation)SSC Eights! (830 reputation)SSC Eights! (830 reputation)SSC Eights! (830 reputation)SSC Eights! (830 reputation)SSC Eights! (830 reputation)

Group: General Forum Members
Points: 830 Visits: 653
Hi ,

The Script is going to give the create statement for all table data type which are present in the database.

So you can get the all the table datatype create script which is used in the database.

Regards,
Mitesh OSwal
+918698619998
William Soranno
William Soranno
SSC-Enthusiastic
SSC-Enthusiastic (118 reputation)SSC-Enthusiastic (118 reputation)SSC-Enthusiastic (118 reputation)SSC-Enthusiastic (118 reputation)SSC-Enthusiastic (118 reputation)SSC-Enthusiastic (118 reputation)SSC-Enthusiastic (118 reputation)SSC-Enthusiastic (118 reputation)

Group: General Forum Members
Points: 118 Visits: 515
Good script.
Here is an improved version that:
- fixes the length = -1 problem for MAX.
- PRINTs the output to the Messages tab to make it easier to copy and past to a new query or to a file.
- adds a USE statement so it is obviouse where the data type came from.
- add the nullablity of the column.


DECLARE
@Stmt VARCHAR(2048)
,@lf CHAR(2) = CHAR(13) + CHAR(10)

DECLARE tmp_cr CURSOR
FOR
SELECT
'USE ' + DB_NAME() + @lf + 'GO' + @lf + 'IF EXISTS(SELECT 1 ' + @lf
+ ' FROM sys.systypes ' + @lf + ' where Name = ''' + st.name + ''')'
+ @lf + ' BEGIN' + @lf + ' DROP TYPE ' + st.name + @lf + @lf
+ ' CREATE TYPE ' + st.name + ' AS TABLE' + @lf + ' ('
+ STUFF((SELECT
' ,' + sc.Name + ' ' + st1.Name + ''
+ CASE WHEN St1.Name IN ('CHAR', 'VARCHAR', 'NVARCHAR')
THEN CASE WHEN sc.xprec = 0
AND SC.xscale = 0
THEN '('
+ CASE WHEN SC.length = -1
THEN 'max'
ELSE CAST(SC.length AS NVARCHAR(100))
END + ') '
ELSE '('
+ CAST(sc.xprec AS NVARCHAR(100))
+ ','
+ CAST(sc.xscale AS NVARCHAR(100))
+ ') '
END
ELSE ' '
END + CASE SC.isnullable
WHEN 1 THEN 'null '
ELSE 'not null '
END + @lf
FROM
sys.syscolumns SC
INNER JOIN sys.systypes st1
ON st1.xtype = sc.xtype
AND st1.xusertype = sc.xusertype
WHERE
st.type_table_object_id = sc.id
FOR
XML PATH('')
,TYPE
).value('.', 'nvarchar(max)'), 1, 2, '') + ' )' + @lf + ' END' + @lf
+ 'GO' AS Stmt
FROM
sys.table_types st

OPEN tmp_cr
WHILE 1 = 1
BEGIN
FETCH NEXT FROM tmp_cr INTO @Stmt
IF @@FETCH_STATUS <> 0
BREAK

PRINT @Stmt
END

CLOSE tmp_cr
DEALLOCATE tmp_cr



The results from running it on msdb look like this:


USE msdb
GO
IF EXISTS(SELECT 1
FROM sys.systypes
where Name = 'syspolicy_target_filters_type')
BEGIN
DROP TYPE syspolicy_target_filters_type

CREATE TYPE syspolicy_target_filters_type AS TABLE
(target_filter_id int null
,policy_id int null
,type sysname not null
,filter nvarchar(max) not null
,type_skeleton sysname not null
)
END
GO



Bill Soranno
MCP, MCTS, MCITP DBA
Database Administrator
Winona State University
Maxwell 143

"Quality, like Success, is a Journey, not a Destination" - William Soranno '92
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