• I haven't messed with the AND, but I am concerned about function performance over a large number of rows. I created the function as is on a SQL Server 2005 Developer Edition 64-bit, w/SP2 (no CU's), running on Vista Ultimate 64-bit with SP1, on an Intel Q9550 Quad-Core cpu at 2.83GHz and 8 GB of RAM, with SQL Server limited to 4096MB.

    Here's the test code and it's timing:

    SET STATISTICS TIME ON

    SELECT N, N * N AS N_SQUARED, dbo.fnSpellInteger(N * N) AS WORDS

    FROM dbo.Tally

    SET STATISTICS TIME OFF

    (11000 row(s) affected)

    SQL Server Execution Times:

    CPU time = 13681 ms, elapsed time = 14052 ms.

    The dbo.Tally table is just a table of the numbers from 1 to 11000. I then re-wrote this function to make use of dbo.Tally, where I expected to improve execution time significantly because the code would then be set-based. Here's the code and the results:

    CREATE FUNCTION dbo.fnIntegerInWords ( @number int )

    RETURNS varchar(100)

    AS

    BEGIN

    /* -- PUT slash asterisk at the beginning of this line, but for testing remove it

    DECLARE @number int

    SET @number = 123456789

    */ -- PUT asterisk slash at the beginning of this line, but for testing remove it

    IF @number < 0 RETURN 'ERROR, NEGATIVE NUMBER USED'

    IF @number = 0 RETURN 'Zero'

    DECLARE @result varchar(100), @cn varchar(12)

    DECLARE @NUMWORDS TABLE (

    Num varchar(2) NOT NULL PRIMARY KEY CLUSTERED,

    Word varchar(9)

    )

    INSERT INTO @NUMWORDS (Num, Word)

    SELECT '0', '' UNION ALL

    SELECT '1', 'One' UNION ALL

    SELECT '2', 'Two' UNION ALL

    SELECT '3', 'Three' UNION ALL

    SELECT '4', 'Four' UNION ALL

    SELECT '5', 'Five' UNION ALL

    SELECT '6', 'Six' UNION ALL

    SELECT '7', 'Seven' UNION ALL

    SELECT '8', 'Eight' UNION ALL

    SELECT '9', 'Nine' UNION ALL

    SELECT '10', 'Ten' UNION ALL

    SELECT '11', 'Eleven' UNION ALL

    SELECT '12', 'Twelve' UNION ALL

    SELECT '13', 'Thirteen' UNION ALL

    SELECT '14', 'Fourteen' UNION ALL

    SELECT '15', 'Fifteen' UNION ALL

    SELECT '16', 'Sixteen' UNION ALL

    SELECT '17', 'Seventeen' UNION ALL

    SELECT '18', 'Eighteen' UNION ALL

    SELECT '19', 'Nineteen' UNION ALL

    SELECT '2_', 'Twenty' UNION ALL

    SELECT '3_', 'Thirty' UNION ALL

    SELECT '4_', 'Forty' UNION ALL

    SELECT '5_', 'Fifty' UNION ALL

    SELECT '6_', 'Sixty' UNION ALL

    SELECT '7_', 'Seventy' UNION ALL

    SELECT '8_', 'Eighty' UNION ALL

    SELECT '9_', 'Ninety'

    SET @cn = RIGHT('00000000000' + CAST(@number AS VARCHAR(10)),12) -- Pad the left with zeros to make the length divisible by 3.

    DECLARE @STR TABLE (

    RN int IDENTITY(1,1) NOT NULL PRIMARY KEY CLUSTERED,

    STRING char(3) NOT NULL,

    WORD AS CAST(CASE RN WHEN 1 THEN ' Billion' WHEN 2 THEN ' Million' WHEN 3 THEN ' Thousand' WHEN 4 THEN '' END AS varchar(9))

    )

    INSERT INTO @STR (STRING)

    SELECT SUBSTRING(@cn,T.N,3) AS STRING

    FROM dbo.Tally AS T

    WHERE T.N < 11 AND (T.N % 3) = 1

    /* -- Remove for testing

    SELECT *

    FROM @STR

    */ -- Remove for testing

    SET @result = ''

    SELECT @result = @result +

    -- FIRST DIGIT OF THREE

    CASE LEFT(S.STRING,1)

    WHEN '0' THEN ''

    ELSE (SELECT Word FROM @NUMWORDS WHERE Num = LEFT(S.STRING,1)) + ' Hundred '

    END +

    -- DIGITS TWO AND THREE

    CASE

    WHEN RIGHT(S.STRING,2) = '00' THEN ''

    WHEN RIGHT(S.STRING,2) LIKE '0_' THEN (SELECT Word FROM @NUMWORDS WHERE Num = RIGHT(S.STRING,1))

    ELSE (SELECT Word FROM @NUMWORDS WHERE LEN(Num) = 2 AND RIGHT(S.STRING,2) LIKE Num) +

    CASE

    WHEN SUBSTRING(S.STRING,2,1) <> '1' AND RIGHT(S.STRING,1) <> '0' THEN '-' + (SELECT Word FROM @NUMWORDS WHERE Num = RIGHT(S.STRING,1))

    ELSE ''

    END

    END +

    -- DIGIT GROUP VALUE

    CASE

    WHEN S.STRING = '000' THEN ''

    ELSE S.WORD

    END + ' '

    FROM @STR AS S

    RETURN LTRIM(RTRIM(@result))

    END

    GO

    SET STATISTICS TIME ON

    SELECT N, N * N AS N_SQUARED, dbo.fnIntegerInWords(N * N) AS WORDS

    FROM dbo.Tally

    SET STATISTICS TIME OFF

    (11000 row(s) affected)

    SQL Server Execution Times:

    CPU time = 4992 ms, elapsed time = 5213 ms.

    Steve

    (aka smunson)

    :):):)

    Steve (aka sgmunson) 🙂 🙂 🙂
    Rent Servers for Income (picks and shovels strategy)