Introduction
In my first article, Telephone Numbers in SQL Server 2005: Part 1 – The Data Type, I discussed various ways of persisting a simple telephone number in SQL Server. Simply displaying the raw data stored in SQL Server would not be suitable for human consumption, so some form of data formatting must be done. Data formatting is usually performed in the user interface layer, for example, by the ASPX page or the WinForms application. Often, it is convenient to have SQL Server format the data in a view to be passed into another document, like a report that might have a difficult time formatting the number correctly. In this article, I will discuss a couple methods that can be used to format a phone number for presentation to the user on SQL Server.
The UDF
SQL Server 2000 introduced the ability to create User Defined Functions. Using a custom formatting function for telephone numbers is a perfect example of where to use UDFs. The code below can be used to create a telephone number formatting function in TSQL:
CREATE FUNCTION [dbo].[FORMATPHONENUMBER]
(
@Number money
)
RETURNS varchar(25)
AS
BEGIN
DECLARE @Formatted varchar(25)
DECLARE @CharNum varchar(18)
DECLARE @Extension int
DECLARE @Numerator bigint
IF @Number IS NULL
BEGIN
RETURN NULL
END
SET @Numerator = CAST(@Number * 10000 AS bigint)
SET @Extension = CAST(RIGHT(@Numerator, 4) AS int)
SET @CharNum = CAST(LEFT(@Numerator , LEN(@Numerator) - 4)
AS varchar(18))
IF LEN(@CharNum) = 10
BEGIN
SET @Formatted = '(' + LEFT(@CharNum, 3) + ') ' +
SUBSTRING(@CharNum,4,3) + '-' + RIGHT(@CharNum, 4)
IF @Extension > 0
BEGIN
SET @Formatted = @Formatted + ' ext '+
CAST(@Extension AS varchar(4))
END
RETURN @Formatted
END
IF LEN(@CharNum) = 7
BEGIN
SET @Formatted = LEFT(@CharNum, 3) + '-' + RIGHT(@CharNum, 4)
IF @Extension > 0
BEGIN
SET @Formatted = @Formatted + ' ext '+
CAST(@Extension AS varchar(6))
END
RETURN @Formatted
END
IF LEN(@CharNum) = 11
BEGIN
SET @Formatted = LEFT(@CharNum, 1) + ' (' + SUBSTRING(@CharNum, 2, 3) + ') ' +
SUBSTRING(@CharNum,4,3) + '-' + RIGHT(@CharNum, 4)
IF @Extension > 0
BEGIN
SET @Formatted = @Formatted + ' ext '+ CAST(@Extension AS varchar(4))
END
RETURN @Formatted
END
SET @Formatted = @CharNum
IF @Extension > 0
BEGIN
SET @Formatted = @Formatted + ' ext '+ CAST(@Extension AS varchar(4))
RETURN 'ext '+ CAST(@Extension AS varchar(4))
END
RETURN @Formatted
END
The CLR Version
SQL Server 2005 added the ability to write your own DLLs in the .NET programming language of your choice, so I also wrote the equivalent function in C#. To do this in Visual Studio 2005, start a new SQL Server project, and add a new User-Defined Function. Paste this code into it:
using System;
using System.Data;
using System.Data.SqlClient;
using System.Data.SqlTypes;
using Microsoft.SqlServer.Server;
using System.Text.RegularExpressions;
public partial class UserDefinedFunctions
{
[Microsoft.SqlServer.Server.SqlFunction(
IsDeterministic=true, IsPrecise=true)]
public static SqlString FormatNAPhoneNumber(SqlMoney Number)
{
if (Number.IsNull)
return SqlString.Null;
string phoneNumber = Number.ToString();
string [] phone = phoneNumber.Split(new Char [] {'.'});
string charnum = phoneNumber;
int extension = int.Parse(phone[1]);
switch (phone[0].Length)
{
case 10:
{
if (extension > 0)
{
charnum = string.Format("({0}) {1}-{2} ext{3}",
phone[0].Substring(0, 3),
phone[0].Substring(3, 3),
phone[0].Substring(6),
extension.ToString());
return new SqlString(charnum);
}
else
{
charnum = string.Format("({0}) {1}-{2}",
phone[0].Substring(0, 3),
phone[0].Substring(3, 3),
phone[0].Substring(6));
return new SqlString(charnum);
}
break;
}
case 7:
{
if (extension > 0)
{
charnum = string.Format("{0}-{1} ext{2}",
phone[0].Substring(0, 3),
phone[0].Substring(3),
extension.ToString());
return new SqlString(charnum);
break;
}
else
{
charnum = string.Format("{0}-{1}",
phone[0].Substring(0, 3),
phone[0].Substring(3));
return new SqlString(charnum);
break;
}
}
case 11:
{
if (extension > 0)
{
charnum = string.Format("{0} ({1}) {2}-{3} ext{4}",
phone[0].Substring(0, 1),
phone[0].Substring(1, 3),
phone[0].Substring(4, 3),
phone[0].Substring(7),
extension.ToString());
return new SqlString(charnum);
}
else
{
charnum = string.Format("{0} ({1}) {2}-{3}",
phone[0].Substring(0, 1),
phone[0].Substring(1, 3),
phone[0].Substring(4, 3),
phone[0].Substring(7));
return new SqlString(charnum);
}
}
default:
{
return new SqlString(charnum);
break;
}
}
}
}
I did some quick benchmarking, to see how it affected performance, against a simple table containing the phone number data type. The table contains a small set of 580 rows, and the SQL SELECT
command was executed 1,000 times, which generated 580,000 calls to the function. The SELECT
command was executed without bringing the dataset back to the client so that the network time was minimized. Execution times are in milliseconds. Your numbers may vary, but use these numbers as a relative comparison of the different methods.
Method
| Time
| Function Overhead
|
No phone number formatting
| 1950 ms
| |
TSQL FORMATPHONENUMBER
| 7450 ms
| 5500 ms
|
C# function using String.Format
| 4750 ms
| 2800 ms
|
C# function using RegEx
| 7187 ms
| 5237 ms
|
The Suprise!
To my surprise, the .NET function call ran twice as fast as the native TSQL function! My first guess would be that the native TSQL functions would certainly run faster by eliminating the overhead of the .NET engine and interface. It seems Microsoft has done their homework on .NET integration. This is another good example of where testing shows results that are often counter to what you would expect.
The C# version also has various lines commented out if you choose to use the RegEx library or the simple string concatenate operator for formatting the telephone number. One way to handle international phone numbers would be to store the RegEx pattern and evaluator strings in a table keyed by country. This table could then be linked to the phone number and the appropriate formatting codes passed to the function. I didn't go this far with the design, but I did try using the RegEx method of formatting to test the performance over using the String.Format
method. As you can see, it performed about the same as the TSQL version, so the overhead of the RegEx object was significant.
Conclusion
Using TSQL to write user defined functions can be awkward if it requires a fair amount of string manipulation or complicated logic. Using the .NET CLR integration allows you to easily use the full power of the .NET library and probably get better performance than with TSQL.
In my first article, it was stated that the small details make all the difference. By paying attention to proper design and doing a little bit of testing, we have cut the data footprint of storing a phone number in half as well as cut the CPU requirements for formatting the number in half. Small changes like these can make all the difference when it comes to how well your applications can scale.