Home Forums SQL Server 2008 T-SQL (SS2K8) Capitalizing only first letter of each Word in a Column using Query RE: Capitalizing only first letter of each Word in a Column using Query

  • -- CREATE SOME SAMPLE DATA TO USE TO TEST THE SOLUTION

    IF object_id('tempdb..#temp') IS NOT NULL

    BEGIN;

    DROP TABLE #temp;

    END;

    SELECT ID, VAL

    INTO #temp

    FROM (VALUES(1,'ABC DEF GHI JKL'),

    (2,'DEF DEF GHI JKL'),

    (3,'D DEF GHI JKL'))a(ID,VAL);

    GO

    -- BEGINNING OF SOLUTION

    IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[DelimitedSplit8K]') AND xtype IN (N'FN', N'IF', N'TF'))

    BEGIN;

    DROP FUNCTION [dbo].[DelimitedSplit8K];

    END;

    GO

    CREATE FUNCTION [dbo].[DelimitedSplit8K]

    -- See http://www.sqlservercentral.com/articles/Tally+Table/72993/

    --===== Define I/O parameters

    (@pString VARCHAR(8000), @pDelimiter CHAR(1))

    --WARNING!!! DO NOT USE MAX DATA-TYPES HERE! IT WILL KILL PERFORMANCE!

    RETURNS TABLE WITH SCHEMABINDING AS

    RETURN

    --===== "Inline" CTE Driven "Tally Table" produces values from 1 up to 10,000...

    -- enough to cover VARCHAR(8000)

    WITH E1(N) AS (

    SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL

    SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL

    SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1

    ), --10E+1 or 10 rows

    E2(N) AS (SELECT 1 FROM E1 a, E1 b), --10E+2 or 100 rows

    E4(N) AS (SELECT 1 FROM E2 a, E2 b), --10E+4 or 10,000 rows max

    cteTally(N) AS (--==== This provides the "base" CTE and limits the number of rows right up front

    -- for both a performance gain and prevention of accidental "overruns"

    SELECT TOP (ISNULL(DATALENGTH(@pString),0)) ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) FROM E4

    ),

    cteStart(N1) AS (--==== This returns N+1 (starting position of each "element" just once for each delimiter)

    SELECT 1 UNION ALL

    SELECT t.N+1 FROM cteTally t WHERE SUBSTRING(@pString,t.N,1) = @pDelimiter

    ),

    cteLen(N1,L1) AS(--==== Return start and length (for use in substring)

    SELECT s.N1,

    ISNULL(NULLIF(CHARINDEX(@pDelimiter,@pString,s.N1),0)-s.N1,8000)

    FROM cteStart s

    )

    --===== Do the actual split. The ISNULL/NULLIF combo handles the length for the final element when no delimiter is found.

    SELECT ItemNumber = ROW_NUMBER() OVER(ORDER BY l.N1),

    Item = SUBSTRING(@pString, l.N1, l.L1)

    FROM cteLen l

    ;

    GO

    -- HOW DO WE USE THE SOLUTION ?

    SELECT a.ID, a.VAL, ca.VAL

    FROM #temp a

    CROSS APPLY (SELECT STUFF((SELECT ' '+UPPER(SUBSTRING(c.Item,1,1))+LOWER(SUBSTRING(c.Item,2,LEN(c.Item)-1))

    FROM #temp b

    CROSS APPLY [dbo].[DelimitedSplit8K](b.VAL,' ') c

    WHERE a.ID = b.ID

    ORDER BY c.ItemNumber

    FOR XML PATH(''), TYPE

    ).value('.','NVARCHAR(MAX)'),1,1,''

    )

    )ca(VAL);

    -- RESULTS

    ID VAL VAL

    ----------- --------------- -----------------

    1 ABC DEF GHI JKL Abc Def Ghi Jkl

    2 DEF DEF GHI JKL Def Def Ghi Jkl

    3 D DEF GHI JKL D Def Ghi Jkl


    Forever trying to learn
    My blog - http://www.cadavre.co.uk/
    For better, quicker answers on T-SQL questions, click on the following...http://www.sqlservercentral.com/articles/Best+Practices/61537/
    For better, quicker answers on SQL Server performance related questions, click on the following...http://www.sqlservercentral.com/articles/SQLServerCentral/66909/