using *tables* as Table-Valued Parameters (TVP)
No, you can't leverage an existing table definition, you need to define an explicit type. This was asked for back in 2007 and was closed as "won't fix" but I still strongly encourage you to up-vote and leave a comment describing your use case and how this will help your business be more productive. You could even point to this question to demonstrate how tedious it can be to try and automate this.
- Item on UserVoice (Formerly Connect #294130)
You can do this today, dynamically, though... for example for your simple definition:
-- you would pass these two in as parameters of course:
DECLARE
@TableName SYSNAME = N'LocationTable',
@TypeName SYSNAME = N'LocationTypeTable';
DECLARE @sql NVARCHAR(MAX) = N'';
SELECT @sql = @sql + N',' + CHAR(13) + CHAR(10) + CHAR(9)
+ QUOTENAME(c.name) + ' '
+ s.name + CASE WHEN LOWER(s.name) LIKE '%char' THEN
'(' + CONVERT(VARCHAR(12), (c.max_length/
(CASE LOWER(LEFT(s.name, 1)) WHEN N'n' THEN 2 ELSE 1 END))) + ')'
ELSE '' END
-- need much more conditionals here for other data types
FROM sys.columns AS c
INNER JOIN sys.types AS s
ON c.system_type_id = s.system_type_id
AND c.user_type_id = s.user_type_id
WHERE c.[object_id] = OBJECT_ID(@TableName);
SELECT @sql = N'CREATE TYPE ' + @TypeName
+ ' AS TABLE ' + CHAR(13) + CHAR(10) + '(' + STUFF(@sql, 1, 1, '')
+ CHAR(13) + CHAR(10) + ');';
PRINT @sql;
-- EXEC sp_executesql @sql;
Results:
CREATE TYPE LocationTypeTable AS TABLE
(
[LocationName] varchar(50),
[CostRate] int
);
Disclaimer: This does not deal with all kinds of other things like MAX types, precision and scale for numerics, etc. The final solution would have to be more robust to account for all potential column definitions but this should give you a start.
In SQL Server 2012 there are new DMVs and stored procedures that will make it much easier to derive column metadata from existing tables (or stored procedures or even ad hoc queries) without having to mess with all the conditional logic against sys.types and sys.columns. I blogged briefly about these enhancements in December. It's still tedious, but it's somewhere between the awful unmaintainable spaghetti above and the ability to just say " as copy of [table x]"...
I dealt with this issue by creating following stored procedure to create a type with same schema existing table may have.
CREATE PROCEDURE [dbo].[Sp_DefineTypeOutOfTableSchema] --or e.g. usp_DefineTypeFromTable
@TableNames NVARCHAR(500)
AS
BEGIN
DECLARE @TableName NVARCHAR(100)
DECLARE @strSQL NVARCHAR(max)
DECLARE @strSQLCol NVARCHAR(1000)
DECLARE @ColName NVARCHAR(100)
DECLARE @ColDataTaype NVARCHAR(50)
DECLARE @ColDefault NVARCHAR(50)
DECLARE @ColIsNulable NVARCHAR(50)
DECLARE @ColFirst NVARCHAR(50)
DECLARE @ColSecond NVARCHAR(50)
DECLARE @ColID NVARCHAR(50)
DECLARE @ColCompute NVARCHAR(50)
IF LEN(@TableNames) > 0 SET @TableNames = @TableNames + ','
WHILE LEN(@TableNames) > 0
BEGIN
SELECT @TableName = TRIM(LEFT(@TableNames, CHARINDEX(',', @TableNames) - 1))
DECLARE schemaCur CURSOR FOR
SELECT
c.name as column_name,
t.name as [type_name],
c.is_nullable,
convert(nvarchar(4000), object_definition(ColumnProperty(c.object_id, c.name, 'default'))) as column_default,
CASE
WHEN c.collation_name IS NOT NULL THEN c.max_length
WHEN t.name like 'datetime%' THEN c.scale
WHEN c.scale = 0 THEN NULL
ELSE c.precision
END as firstValue,
CASE
WHEN (c.scale = 0 or t.name like 'datetime%') THEN NULL
ELSE c.scale
END as secondValue,
c.is_identity, -- would be best to know seed,increment
c.is_computed -- should really look up col definition. `convert(nvarchar(4000), object_definition(ColumnProperty(c.object_id, c.name, 'computed')))` as computed ?
FROM sys.columns as c join
sys.all_objects as o
on c.object_id=o.object_id join
sys.types as t
on c.user_type_id=t.user_type_id
WHERE
o.type in ('U','V','TF','IF','TT') and --'S' to include built-in tables/types
o.name = @TableName
ORDER BY o.name, c.column_id
OPEN schemaCur
SELECT @strSQL=''
FETCH NEXT FROM schemaCur
INTO @ColName,@ColDataTaype,@ColIsNulable,@ColDefault,@ColFirst,@ColSecond,@ColID,@ColCompute
WHILE @@FETCH_STATUS = 0 BEGIN
-- SELECT @strSQLCol=''
SELECT @strSQLCol= '['+@ColName+'] '+'[' + @ColDataTaype +'] '
IF @ColSecond is NULL
BEGIN
IF @ColFirst is not NULL SELECT @strSQLCol += '(' + @ColFirst + ') '
END
ELSE SELECT @strSQLCol += '(' + @ColFirst +',' +@ColSecond + ') '
IF @ColID>0 SELECT @strSQLCol += ' IDENTITY(1,1)'
IF @ColIsNulable>0 SELECT @strSQLCol += 'NULL'
ELSE SELECT @strSQLCol += ' NOT NULL'
IF @ColDefault IS NOT NULL SELECT @strSQLCol += ' DEFAULT(' +@ColDefault + '),'
ELSE SELECT @strSQLCol += ','
SELECT @strSQL += @strSQLCol
--print @strSQL
FETCH NEXT FROM schemaCur
INTO @ColName,@ColDataTaype,@ColIsNulable,@ColDefault,@ColFirst,@ColSecond,@ColID,@ColCompute
END
CLOSE schemaCur
DEALLOCATE schemaCur
SELECT @strSQL=left(@strSQL, len(@strSQL)-1)
IF EXISTS (SELECT * FROM sys.types WHERE IS_TABLE_TYPE = 1 AND name = 'tt_' +@TableName)
BEGIN
EXEC('DROP TYPE tt_' +@TableName )
END
SELECT @strSQL = 'CREATE TYPE tt_' + @TableName + ' AS TABLE (' + @strSQL + ')'
-- print @strSQL
EXEC (@strSQL)
SELECT @TableNames = SUBSTRING(@TableNames, CHARINDEX(',', @TableNames) + 1, LEN(@TableNames))
END
END
you can use it like this
Exec Sp_DefineTypeOutOfTableSchema 'Table1name,Table2name'
Erland Sommarskog has an extensive article describing how to use TVP.
Have a look, it's worth it!
In short, you cannot use an existing type, just like Aaron Bertrand's earlier answer. But at least it's a bulk transfer..