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


Can a multistatement table-valued function return a user-defined table type TABLE?


Can a multistatement table-valued function return a user-defined table type TABLE?

Author
Message
Bill Talada
Bill Talada
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1202 Visits: 2001
I've simplified the code as much as possible below. It works but I want to use a "user-defined table type" instead of writing out all the columns in the "returns" table. I don't want to manually maintain the columns returned in table functions so I'd like to use a user-defined table type instead. Can it be done?


----------- make table type dbo.xy
IF EXISTS (SELECT * FROM sys.types st JOIN sys.schemas ss ON st.schema_id = ss.schema_id WHERE st.name = N'xy' AND ss.name = N'dbo')
DROP TYPE dbo.xy
GO

CREATE TYPE dbo.xy AS TABLE
(
x int NOT NULL,
y int NOT NULL
)
GO
----------- make fn DoubleXY
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'dbo.DoubleXY')
AND type in (N'FN', N'IF', N'TF', N'FS', N'FT'))
DROP FUNCTION dbo.DoubleXY
GO

CREATE FUNCTION dbo.DoubleXY (@a int, @b int)
returns @t table (x int, y int)
--next line fails. How can I return @t dbo.xy - a user-defined table type in a multistatement table-valued function?
--returns @t dbo.xy
AS
BEGIN
insert into @t values (@a, @b);
insert into @t values (@a * 2, @b * 2);

RETURN
END
GO

-------------- test
DECLARE @points dbo.xy;

insert into @points
select * from dbo.DoubleXY(5, 7);

insert into @points
select * from dbo.DoubleXY(22, 24);

select * from @points;



Grant Fritchey
Grant Fritchey
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40919 Visits: 32666
According to the documentation, you have to use a table variable. That means defining the columns.

----------------------------------------------------
The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood...
Theodore Roosevelt

The Scary DBA
Author of: SQL Server Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
dwain.c
dwain.c
SSCertifiable
SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)

Group: General Forum Members
Points: 7435 Visits: 6431
With a multi-line TVF like you have there, as Grant points out you need to define the table columns.

If you can convert it into an inline TVF (and the sample you provided could be) there would be no need to define the table columns.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
Bill Talada
Bill Talada
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1202 Visits: 2001
Looking at the history, Microsoft added Tables as a return type in 2005. They added user-defined table types in 2008 so maybe Microsoft never went back extend the grammar. Perhaps it was too much effort. The documentation examples for passing tables as arguments really pushes us to use user-defined table types - that's why this limitation surprises me.

I'm a control freak over parameters. I require developers to use parameter names that match column names; that way I can run automated checks to make sure data types and lengths match before deploying to production.

Passing input, readonly tables is so powerful and object oriented, I love it.
Grant Fritchey
Grant Fritchey
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40919 Visits: 32666
Just don't ever forget that all these types of tables from table variables, multi-statement UDF and table parameters, all of them lack statistics which can seriously, negatively, impact performance.

----------------------------------------------------
The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood...
Theodore Roosevelt

The Scary DBA
Author of: SQL Server Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
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