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


Creating User-Defined Data Types - SQL School Video


Creating User-Defined Data Types - SQL School Video

Author
Message
Andy Warren
Andy Warren
One Orange Chip
One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)One Orange Chip (25K reputation)

Group: Moderators
Points: 25853 Visits: 2747
Comments posted to this topic are about the item Creating User-Defined Data Types - SQL School Video

Andy
SQLAndy - My Blog!
Connect with me on LinkedIn
Follow me on Twitter
steve.saunders-611242
steve.saunders-611242
SSC Rookie
SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)

Group: General Forum Members
Points: 40 Visits: 132
I've been using UDTs for years for those very reasons of consistency & self-documentation you propounded in your video. Updating the UDT has always been its Achilles heel.

Currently
You suggest in the video that UDTs should be assigned retrospectively once the database design has settled down - which almost contradicts their reason to exist! Nevertheless, structures DO change and we must synchronise our types to the new design. Here's a handy 2005 script showing all dependencies for your UDTs. At least you can see which objects you need to change or drop before updating your type. This script could be wrapped into a parameterised SP for refined filtering etc.

use [YourDB]
Select t.name UDT,
o.name Object,
o.type_desc ObjectType,
c.name AttributeName,
c.type_desc AttributeType
From (
SELECT object_id, name, user_type_id, 'SQL_COLUMN' AS type_desc
FROM sys.columns

UNION ALL

SELECT object_id, name, user_type_id, 'SQL_PROCEDURE_PARAMETER'
FROM sys.parameters
) c
JOIN sys.objects o ON o.object_id = c.object_id
JOIN sys.types t ON t.user_type_id = c.user_type_id
Where t.schema_id = 1 -- dbo (see sys.schemas for all other object owners & change as reqd)
order by
UDT,
Object



and here's one for SQL Server 2000.

use [YourDB]
Select t.name UDT,
o.name Object,
t.xusertype ObjectType,
c.name AttributeName,

case o.xtype
when 'P'
then 'SQL_PROCEDURE_PARAMETER'
else 'SQL_COLUMN'
end AttributeType

From syscolumns c
JOIN sysobjects o ON o.id = c.id
JOIN systypes t ON t.usertype = c.xusertype
Where t.uid = 1 -- dbo (see sysusers for other users' IDs)
and o.xtype in ('P','U')
order by
UDT,
Object


Another thing about UDTs: you can't use them in the Convert() or cast() functions! You get "Type xxx is not a defined system type". When are MS going to get that right? (Apologies if this exists in 2008.)

Proposal
But life shouldn't be that hard, and I would propose the following solution for a near-future SQL Server upgrade.

Eliminate UDTs!

In almost all database scripting scenarios, every variable is derived from, or has a relationship with, a table-based field. Why not use that field's type when declaring any variable or SP parameter etc? So, for example, when creating a variable relating to tblClient.EMailAddress, it would be defined as:
declare @EMailAddress tblClient.EMailAddress%Type
The upshot of this extension to the syntax is that all variables' types would be dynamic and would depend on the CURRENT type of the underlying source field at execution time. No need to update anything except the table structure! In the purest form, no type except for those defining table fields would use a system type. Oracle have been doing it for years and it works a treat. From a user/programmer perspective, the change would be painless, rock solid and even more self-documenting than UDTs now. Changing the underlying SQL Server engine to use this proposed syntax may not be be so trivial...
scottcote
scottcote
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 14
I think you are dead on regarding the cumbersome nature of the udt's and about Oracle's typcasting of variables. Wouldn't it be nice to have a stored procedure where you feed in the user defined datatype to be modified as one argument, and the revised definition as the second argument, where upon the sp produces a script that finds all instances and generates the necessary conversion code? (or an SSIS package to do this)

After being diligent over the years to define domain types in erwin and its ilk, this seems like it could be really handy if it weren't so cumbersome.

SCott
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