EnjoY | Database Research And Development: MSSQL SQL : UDF | User Defined Functions – Scalar, Table Valued (TVF), MultiStatement (MTVF)

Saturday, August 29, 2020

MSSQL SQL : UDF | User Defined Functions – Scalar, Table Valued (TVF), MultiStatement (MTVF)

UDF or User Defined Functions are a set or batch of code where one can apply any SQL logic and return a single scalar value or a record set.

According to MS BOL UDFs are the subroutines made up of one or more Transact-SQL statements that can be used to encapsulate code for reuse. These reusable subroutines can be used as:
– In TSQL SELECT statements at column level.
– To create parametrized view or improve the functionality of in indexed view.
– To define a column and CHECK constraints while creating a table.
– To replace a stored procedures and views.
– Join complex logic with a table where a stored procedure fails.
– Faster execution like Stored procedures, reduce compliation cost by caching the execution query plans.

Apart from the benefits UDF’s has certain limitations:
– Can not modify any database objects, limited to update table variables only.
– Can not contain the new OUTPUT clause.
– Can only call extended stored procedures, no other procedures.
– Can not define TRY-CATCH block.
– Some built-in functions are not allowed here, like:GETDATE(), because GETDATE is non-deterministic as its value changes every time it is called. On the other hand DATEADD() is allowed as it is deterministic, because it will return same result when called with same argument values.

A UDF can take 0 or upto 1024 parameters and returns either a scalar value or a table record set depending on its type.
SQL Server supports mainly 3 types of UDFs:
1. Scalar function
2. Inline table-valued function
3. Multistatement table-valued function

1. Scalar function: Returns a single value of any datatype except text, ntext, image, cursor & timestamp.

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
-- Example:
--// Create Scalar UDF [dbo].[ufn_GetContactOrders]
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE FUNCTION [dbo].[ufn_GetContactOrders](@ContactID int)
RETURNS varchar(500)
AS
BEGIN
    DECLARE @Orders varchar(500)
 
    SELECT @Orders = COALESCE(@Orders + ', ', '') + CAST(SalesOrderID as varchar(10))
    FROM Sales.SalesOrderHeader
    WHERE ContactID = @ContactID
 
    RETURN (@Orders)
END
 
--// Usage:
-- Used at COLUMN level with SELECT
SELECT ContactID, dbo.ufn_GetContactOrders(ContactID) FROM Person.Contact
WHERE ContactID between 100 and 105 -- Output below
 
-- Used while defining a computed column while creating a table.
CREATE TABLE tempCustOrders (CustID int, Orders as (dbo.ufn_GetContactOrders(CustID)))
 
INSERT INTO tempCustOrders (CustID)
SELECT ContactID FROM Person.Contact
WHERE ContactID between 100 and 105
 
SELECT * FROM tempCustOrders -- Output below
 
DROP TABLE tempCustOrders
Output of both the selects above:
ContactID	OrdersCSV
100		51702, 57021, 63139, 69398
101		47431, 48369, 49528, 50744, 53589, 59017, 65279, 71899
102		43874, 44519, 46989, 48013, 49130, 50274, 51807, 57113, 63162, 69495
103		43691, 44315, 45072, 45811, 46663, 47715, 48787, 49887, 51144, 55310, 61247, 67318
104		43866, 44511, 45295, 46052, 46973, 47998, 49112, 50215, 51723, 57109, 63158, 69420
105		NULL

Note: If this was a temp(#) table then the function also needs to be created in tempdb, cause the temp table belongs to tempdb. The tables in function should also have the database name prefixed, i.e. [AdventureWorks].[Sales].[SalesOrderHeader]

2. Inline table-valued function: Returns a table i.e. a record-set. The function body contains just a single TSQL statement, which results to a record-set and is returned from here.

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
-- Example:
--// Create Inline table-valued UDF [dbo].[ufn_itv_GetContactSales]
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE FUNCTION [dbo].[ufn_itv_GetContactSales](@ContactID int)
RETURNS TABLE
AS
RETURN (
    SELECT h.[ContactID], h.[SalesOrderID], p.[ProductID], p.[Name], h.[OrderDate], h.[DueDate],
    h.[ShipDate], h.[TotalDue], h.[Status], h.[SalesPersonID]
    FROM Sales.SalesOrderHeader AS h
    JOIN Sales.SalesOrderDetail AS d ON d.SalesOrderID = h.SalesOrderID
    JOIN Production.Product AS p ON p.ProductID = d.ProductID
    WHERE ContactID = @ContactID )
 
--// Usage:
SELECT * FROM ufn_itv_GetContactSales(100)

3. Multistatement table-valued function: Also returns a table (record-set) but can contain multiple TSQL statements or scripts and is defined in BEGIN END block. The final set of rows are then returned from here.

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
-- Example:
--// Create Multistatement table-valued UDF [dbo].[ufn_mtv_GetContactSales]
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE FUNCTION [dbo].[ufn_mtv_GetContactSales](@ContactID int)
RETURNS @retSalesInfo TABLE (
    [ContactID] INT NOT NULL,
    [SalesOrderID] INT NULL,
    [ProductID] INT NULL,
    [Name] NVARCHAR(50) NULL,
    [OrderDate] DATETIME NULL,
    [DueDate] DATETIME NULL,
    [ShipDate] DATETIME NULL,
    [TotalDue] MONEY NULL,
    [Status] TINYINT NULL,
    [SalesPersonID] INT NULL)
AS
BEGIN
    IF @ContactID IS NOT NULL
    BEGIN
        INSERT @retSalesInfo
        SELECT h.[ContactID], h.[SalesOrderID], p.[ProductID], p.[Name], h.[OrderDate], h.[DueDate],
               h.[ShipDate], h.[TotalDue], h.[Status], h.[SalesPersonID]
        FROM Sales.SalesOrderHeader AS h
        JOIN Sales.SalesOrderDetail AS d ON d.SalesOrderID = h.SalesOrderID
        JOIN Production.Product AS p ON p.ProductID = d.ProductID
        WHERE ContactID = @ContactID
    END
    -- Return the recordsets
    RETURN
END
 
--// Usage:
SELECT * FROM ufn_mtv_GetContactSales(100)

— Output:

TVF & MVF output

TVF & MVF output



No comments:

Post a Comment

It’s all about friendly conversation here at small review :) I’d love to be hear your thoughts!

Be sure to check back again because I do make every effort to reply to your comments here.

Featured Post

SQL Server : SELECT all columns to be good or bad in database system

This article is half-done without your Comment! *** Please share your thoughts via Comment *** In this post, I am going to write about one o...

Popular Posts