August 29, 2012 at 3:50 am
HI,
I need to changes User Defined Type's column datatype, and this UDT is using many stored procedure and user defined functions. And my application is live on production.
Is any way to edit UDT?
August 29, 2012 at 4:02 am
And my application is live on production.Is any way to edit UDT?
you should really do this on a dev server and send it for test before you even think about live servers... i assume you have developer or express installed on your own desktop/laptop... why not do it on there first and at least you can unit test it before you think about going any further
HOWEVER you should be able to DROP and CREATE
see the example below which changes the UDT from bigint to int
create proc test as
declare @m dbo.test
set @m=1
GO
/****** Object: UserDefinedDataType [dbo].[test] Script Date: 08/29/2012 09:59:06 ******/
IF EXISTS (SELECT * FROM sys.types st JOIN sys.schemas ss ON st.schema_id = ss.schema_id WHERE st.name = N'test' AND ss.name = N'dbo')
DROP TYPE [dbo].[test]
GO
/****** Object: UserDefinedDataType [dbo].[test] Script Date: 08/29/2012 09:59:06 ******/
CREATE TYPE [dbo].[test] FROM INT NOT NULL
GO
MVDBA
August 29, 2012 at 4:06 am
Hi Mike,
Sure first i will do on local development environment.
Type is being use by many procedure and i dont want to touch those objects.
August 29, 2012 at 4:51 am
as you can see from my example - i didn't touch the proc - just the UDT
MVDBA
August 29, 2012 at 5:56 am
I just tested this: you must drop all the objects that use the type, drop and recreate teh type, and then create all the objects that used to use it all over again.
otherwise you get an error referencing the first dependancy that SQL finds:
Msg 3732, Level 16, State 1, Line 1
Cannot drop type 'intVarcharForConCat' because it is being referenced by object 'ConcatStuff'. There may be other objects that reference this type.
here's a very simple example:
/* Create a user-defined table type */
CREATE TYPE intVarcharForConCat AS TABLE
(
ID int,
Descriptor VARCHAR(50)
);
--now a function that would do the FOR XML for concatenation.
GO
CREATE FUNCTION ConcatStuff(@MyTable dbo.intVarcharForConCat READONLY)
RETURNS TABLE WITH SCHEMABINDING
AS
RETURN(
SELECT DISTINCT
t.ID,
sq.Columns As Descriptors
FROM @MyTable t
INNER HASH JOIN (SELECT
ID,
Columns = STUFF(
(SELECT
',' + Descriptor
FROM @MyTable sc
WHERE sc.ID = s.ID
FOR XML PATH('')
)
,1,1,'')
FROM @MyTable s
) sq ON t.ID = sq.ID
)
GO
--test just the table type:
Declare @MyTable dbo.intVarcharForConCat
INSERT INTO @MyTable
SELECT OBJECT_ID,name from sys.columns
SELECT * FROM @MyTable
--test the concat function
SELECT * FROM dbo.ConcatStuff(@MyTable)
--try to drop and recreate just the type:
DROP TYPE intVarcharForConCat AS TABLE
CREATE TYPE intVarcharForConCat AS TABLE
(
ID int,
Descriptor VARCHAR(60)--creasing the size, for example
);
--now cleanup
DROP FUNCTION ConcatStuff
DROP TYPE intVarcharForConCat;
Lowell
August 29, 2012 at 7:48 am
i just did the same thing for a UDT (as per the original post) rather than a table type and you seem to be able to do it.... possibly because UDT originate from old school SQL
MVDBA
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply