User-Defined Functions
SQL Server user-defined functions are created using the CREATE FUNCTION command. Any created function can take zero or more input parameters of any type except timestamp, cursor, or table. User-defined functions pass back a single value as defined in the RETURNS section of the CREATE FUNCTION command. User-defined functions can return any data type except text, ntext, image, cursor, or timestamp.
All user-defined functions must comply with all naming standards set forth for all objects in the database. Unlike other objects in the database, when you call a user-defined function, you must use the qualified object name, in the format of owner_name.function_name, as follows:
SELECT * FROM dbo.fncReturnScalarValue
As with all rules, there is an exception to the owner_name.function_name rule. With built-in functions that return tables, you must preface the name of the function with two colons (::), as follows:
SELECT * FROM ::fn_helpcollations()
To create user-defined functions, you must have been assigned the CREATE FUNCTION permission. Before other users can use your function, you must assign them EXECUTE permission on the function. Also, if you create a table that references a user-defined function as either a computed column, a CHECK constraint, or a DEFAULT, you must own both the table and the function.
With all objects that you can create, there is also a list of things that you can and can't do. The following are the rules that go along with user-defined functions.
-
The function can't perform any actions that have side effects. This basically means that the function can't perform any changes to a resource outside the function itself. You can't create a procedure that modifies data in a table, performs cursor operations on cursors that aren't local to the procedure, sends email, creates database objects, or generates a result set that is returned to the user.
-
Values can be assigned to local variables.
-
The DECLARE statement can be used to create variables and cursors local to the procedure.
-
Cursor operations including DECLARE, OPEN, FETCH, CLOSE, and DEALLOCATE can all be performed in the cursor. FETCH statements in the function can't be used to return data to the user. FETCH statements in functions can be used only to assign values to local variables using the INTO keyword.
-
All control-of-flow statements are allowed in the context of the procedure.
-
SELECT statements that return values to the user aren't allowed. The only allowable SELECT statements assign values to local variables.
-
UPDATEs, INSERTs, and DELETEs to objects external to the function aren't permitted. UPDATEs, INSERTs, and DELETEs to table variables local to the function are permitted.
-
The last statement in a function must be a RETURN statement.
-
User-defined functions can't contain any function that returns different data every time it is run. These functions include the following:
@@CONNECTIONS |
@@TIMETICKS |
@@CPU_BUSY |
@@TOTAL_ERRORS |
@@IDLE |
@@TOTAL_READ |
@@IO_BUSY |
@@TOTAL_WRITE |
@@MAX_CONNECTIONS |
GETDATE |
@@PACK_RECEIVED |
NEWID |
@@PACK_SENT |
RAND |
@@PACKET_ERRORS |
TEXTPTR |
All these rules are checked when the function is parsed, and, if any one of them is broken, the function creation fails and an error is returned. If all the rules are followed and the procedure is syntactically correct, the procedure will be created and stored in the sysobjects and syscomments tables. The following is the syntax for the CREATE FUNCTION command:
CREATE FUNCTION [owner_name.]function_name ( [ {@parameter_name scalar_data_type [= default]} [,...n] ] ) RETURNS scalar_data_type | TABLE(column_definition | table_constraint [,...n]) [WITH ENCRYPTION | SCHEMABINDING [,...n] ] [AS] [BEGIN function_body END] | RETURN [(] select_statement [)]
The CREATE FUNCTION command syntax is explained in Table 1.
Table 1 CREATE FUNCTION Syntax
Element |
Description |
CREATE FUNCTION |
This statement tells SQL Server that you are going to create a function object in the current database. |
owner_name |
This is a placeholder for an optional object owner name. You don't have to specify an owner. If you don't, the person who created the object owns it. |
function_name |
This is a placeholder for the name of the function that you are creating. |
@parameter_name |
If the function being created will accept input parameters, this is where you declare them. This process is similar to created parameters for stored procedures. |
scalar_data_type |
This is the data type for the input parameter. A function can take any data type as a parameter except the timestamp, cursor, and table data types. |
= default |
If you want to provide a default value for the parameter when the user doesn't pass one in, this is where you do so. This is similar to the way you would create a default value in a stored procedure. |
,...n |
This indicates that you can create multiple parameters that can be passed into the function. Any function that you create can take up to 1,024 parameters. |
RETURNS |
This section tells SQL Server what data type the function will return. You can return either a single scalar value or a table. |
scalar_data_type |
If you are going to return a single scalar value, this is where you tell SQL Server the data type, length, and precision of the data type. |
TABLE |
This data type enables you to return multiple rows of data from a function. |
column_definition |
This placeholder shows you where the column definitions for the TABLE data type will go. You define columns in the TABLE data type in the same manner that you do when creating a table. |
table_constraint |
This placeholder shows you that, like a regular table, you can define table constraints on the TABLE data type. |
,...n |
This indicates that you can have multiple column definitions and table constraints in the TABLE data type. |
WITH ENCRYPTION |
This option indicates that the function's code will be encrypted in the syscomments table. |
WITH SCHEMABINDING |
This option indicates that the function that is created is bound to all objects that it references. |
,...n |
This indicates that you can use multiple options when you are creating functions. Currently, there are only two options, but there can be many more. |
AS |
This keyword alerts SQL Server that the code for the function is about to begin. |
BEGIN |
This keyword, used with the END function, delimits the code for the function. |
function_body |
This is a placeholder for the code in function. |
END |
This keyword, used with the BEGIN function, delimits the code for the function. |
RETURN |
This statement sends a value back to the calling procedure. |
select_statement |
This placeholder can be used with the RETURN statement to send a value back to the calling procedure. |
One note on the WITH SCHEMABINDING option: When a function is created with the WITH SCHEMABINDING option, any objects referenced in the function can't be altered or dropped while the function still exists. The binding of the function is removed and the referenced objects can be dropped or altered only if the function is dropped or the function is altered and the WITH SCHEMABINDING option isn't specified. A function can be schema-bound only if all the following conditions are true:
-
Any user-defined functions or views referenced by the function to be schema-bound are also schema-bound.
-
The objects referenced by the function aren't referenced using a three- or four-part name.
-
The function and any objects referenced by the function are all contained in the same database.
-
The user creating the object has REFERENCES permissions on all objects referenced in the database.
User-defined functions can be either scalar or tabular. A scalar function returns a single value to the user using the RETURN statement. A tabular function returns several values in a table.
User-defined scalar functions can be used in a SQL statement where the data type that's returned from the function can be used. Take, for example, the code in Listing 1. This function returns a datetime value of three business days from the date that was passed in.
Listing 1 The First Function
CREATE FUNCTION fncGetThreeBusinessDays(@dtmDateStart DATETIME) RETURNS DATETIME AS BEGIN IF DATEPART(dw, @dtmDateStart) = 4 BEGIN RETURN(DATEADD(dw, 5, @dtmDateStart)) END ELSE IF DATEPART(dw, @dtmDateStart) = 5 BEGIN RETURN(DATEADD(dw, 5, @dtmDateStart)) END ELSE IF DATEPART(dw, @dtmDateStart) = 6 BEGIN RETURN(DATEADD(dw, 5, @dtmDateStart)) END ELSE IF DATEPART(dw, @dtmDateStart) = 7 BEGIN RETURN(DATEADD(dw, 4, @dtmDateStart)) END RETURN(DATEADD(dw, 3, @dtmDateStart)) END
To test this stored procedure, you can run the code in Listing 2. This script enables you to enter a date in the @dtmDate variable. The script will show you the day that this date represents and then the name of the day after three business days.
Listing 2 Using the fncGetThreeBusinessDays Function
DECLARE @dtmDate DATETIME SELECT @dtmDate = '3/12/2000' SELECT DATENAME(dw, @dtmDate) SELECT DATENAME(dw, dbo.fncGetThreeBusinessDays(@dtmDate))
It's possible to use scalar functions in tables. Doing this creates a computed column in the table where the function is used. The code in Listing 3 creates a table that uses the fncGetThreeBusinessDays function created in Listing 1 to determine a product's expected delivery date. The script then populates the table and retrieves the data from the table so you can see the results.
Listing 3 Using Functions as Computed Columns
CREATE TABLE OrderInfo ( OrderID INT NOT NULL, ShippingMethod VARCHAR(16) NOT NULL, OrderDate DATETIME NOT NULL DEFAULT GETDATE(), ExpectedDate AS ( dbo.fncGetThreeBusinessDays(OrderDate) ) ) GO INSERT OrderInfo VALUES (1, 'UPS GROUND', GETDATE()) INSERT OrderInfo VALUES (2, 'FEDEX STANDARD', DATEADD(dd, 2, GETDATE())) INSERT OrderInfo VALUES (3, 'PRIORITY MAIL', DATEADD(dd, 4, GETDATE())) GO SELECT OrderID, ShippingMethod, CONVERT(VARCHAR(12), OrderDate, 1) + '(' + DATENAME(dw, OrderDate) + ')' AS 'OrderDate', CONVERT(VARCHAR(12), ExpectedDate, 1) + '(' + DATENAME(dw, ExpectedDate) + ')' AS 'ExpectedDate' FROM OrderInfo GO