Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 1234»»»

ProperCase Function Expand / Collapse
Author
Message
Posted Thursday, January 16, 2014 8:42 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: 2 days ago @ 4:41 AM
Points: 356, Visits: 2,611
I'm having an issue converting a scalar function into Table-Valued function and was hoping some of the minds on this forum would be able to help.

Here is the original Function:

CREATE FUNCTION [Utility].[f_ProperCase] 
(
@strIn VARCHAR(255)
)
RETURNS VARCHAR(255)
AS
BEGIN
IF @strIn IS NULL
RETURN NULL

DECLARE
@strOut VARCHAR(255),
@i INT,
@Up BIT,
@c VARCHAR(2)

SELECT
@strOut = '',
@i = 0,
@Up = 1

WHILE @i <= DATALENGTH(@strIn)
BEGIN
SET @c = SUBSTRING(@strIn,@i,1)
IF @c IN (' ','-','''')
BEGIN
SET @strOut = @strOut + @c
SET @Up = 1
END
ELSE
BEGIN
IF @up = 1
SET @c = UPPER(@c)
ELSE
SET @c = LOWER(@c)

SET @strOut = @strOut + @c
SET @Up = 0
END
SET @i = @i + 1
END
RETURN @strOut
END

Here is my attempt at a Table Valued Function to perform the same task:

CREATE FUNCTION [dbo].[ProperCase]
(
@StrIn VARCHAR(255)
)
RETURNS TABLE WITH SCHEMABINDING
AS
RETURN
SELECT ProperCaseString = (
SELECT CASE
WHEN GN.N = 1 THEN UPPER(SUBSTRING(@StrIn,GN.N,1))
WHEN SUBSTRING(@StrIn,GN.N-1,1) IN (' ','-','''') THEN UPPER(SUBSTRING(@StrIn,GN.N,1))
ELSE LOWER(SUBSTRING(@StrIn,GN.N,1))
END AS [text()]
FROM dbo.GetNums(1,ISNULL(LEN(@StrIn),1)) AS GN
FOR XML PATH('')
);
GO

Part of the issue is that the XML concatenation is converting the blanks spaces into "& # x 2 0;" . I think I've found a way to correct this and get the output i would like (Shown in the below code):

DECLARE @StringTest TABLE
(
StrIn VARCHAR(255)
)
INSERT INTO @StringTest(StrIn)
VALUES ('thIS iS A StRing'),
('ANOTHEr STRING'),
('again another string')

--Converts special characters
SELECT CA1.ProperCase AS ProperCase
FROM @StringTest AS ST
CROSS APPLY (
SELECT CASE
WHEN GN.N = 1 THEN UPPER(SUBSTRING(ST.StrIn,GN.N,1))
WHEN SUBSTRING(ST.StrIn,GN.N-1,1) IN (' ','-','''') THEN UPPER(SUBSTRING(ST.StrIn,GN.N,1))
WHEN SUBSTRING(ST.StrIn,GN.N,1) = ' ' THEN CHAR(32)
ELSE LOWER(SUBSTRING(ST.StrIn,GN.N,1))
END AS [text()]
FROM dbo.GetNums(1,ISNULL(LEN(ST.StrIn),1)) AS GN
FOR XML PATH('')
) AS CA1 (ProperCase)

--Shows special characters i.e. space as a space
SELECT CA1.ProperCase.value('/MyString[1]','varchar(8000)') AS ProperCase
FROM @StringTest AS ST
CROSS APPLY (
SELECT CASE
WHEN GN.N = 1 THEN UPPER(SUBSTRING(ST.StrIn,GN.N,1))
WHEN SUBSTRING(ST.StrIn,GN.N-1,1) IN (' ','-','''') THEN UPPER(SUBSTRING(ST.StrIn,GN.N,1))
WHEN SUBSTRING(ST.StrIn,GN.N,1) = ' ' THEN CHAR(32)
ELSE LOWER(SUBSTRING(ST.StrIn,GN.N,1))
END AS [text()]
FROM dbo.GetNums(1,ISNULL(LEN(ST.StrIn),1)) AS GN
FOR XML PATH(''), root('MyString'), type
) AS CA1 (ProperCase)

The main part of the issue though, and the long winded point of this post, is that i cannot seem to reflect this in a function
CREATE FUNCTION [dbo].[ProperCase]
(
@StrIn VARCHAR(255)
)
RETURNS TABLE WITH SCHEMABINDING
AS
RETURN
SELECT ProperCaseString = (
SELECT SQ1.[text()].value('/MyString[1]','varchar(8000)')
FROM
(SELECT CASE
WHEN GN.N = 1 THEN UPPER(SUBSTRING(@StrIn,GN.N,1))
WHEN SUBSTRING(@StrIn,GN.N-1,1) IN (' ','-','''') THEN UPPER(SUBSTRING(@StrIn,GN.N,1))
WHEN SUBSTRING(@StrIn,GN.N,1) = ' ' THEN ' '
ELSE LOWER(SUBSTRING(@StrIn,GN.N,1))
END AS [text()]
FROM dbo.GetNums(1,ISNULL(LEN(@StrIn),1)) AS GN
FOR XML PATH(''), root('MyString'), type
) AS SQ1
);
GO

I get the follow error when I try to create the function:
Msg 8155, Level 16, State 2, Procedure ProperCase, Line 24
No column name was specified for column 1 of 'SQ1'.
Msg 207, Level 16, State 1, Procedure ProperCase, Line 13
Invalid column name 'text()'.

Any suggestions/Improvements welcome!
Post #1531616
Posted Thursday, January 16, 2014 9:08 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: 2 days ago @ 4:41 AM
Points: 356, Visits: 2,611
Think I may have figured it out:

CREATE FUNCTION [dbo].[ProperCase]
(
@StrIn VARCHAR(255)
)
RETURNS TABLE WITH SCHEMABINDING
AS
RETURN
SELECT ProperCaseString = (
(SELECT CASE
WHEN GN.N = 1 THEN UPPER(SUBSTRING(@StrIn,GN.N,1))
WHEN SUBSTRING(@StrIn,GN.N-1,1) IN (' ','-','''') THEN UPPER(SUBSTRING(@StrIn,GN.N,1))
ELSE LOWER(SUBSTRING(@StrIn,GN.N,1))
END AS [text()]
FROM dbo.GetNums(1,ISNULL(LEN(@StrIn),1)) AS GN
FOR XML PATH(''), TYPE
).value('.','varchar(8000)')
);

Now to see if it actually is an improvement!

And if anyone has anything to add please do.
Post #1531638
Posted Thursday, January 16, 2014 9:19 AM
SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Today @ 1:48 PM
Points: 4,053, Visits: 3,490
You have definitely peaked my interest with this one. I've been playing with adapting Jeff Moden's DelimitedSplit8K function covered in the article at http://www.sqlservercentral.com/articles/Tally+Table/72993, but I don't have your solution yet. I'm running into the case where multiple trailing spaces is killing it. Then there's the matter of allowing for more than one delimiter at once. I don't know if I'm running down a rabbit hole with no hope here, but it is definitely cool stuff.

I'm curious as to the performance when using the XML approach versus the tally table approach, so please post your performance testing results.



Tally Tables - Performance Personified
String Splitting with True Performance
Best practices on how to ask questions
Post #1531647
Posted Thursday, January 16, 2014 9:24 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 9:48 PM
Points: 3,636, Visits: 8,151
Hi,
I'm not sure what your GetNums function looks like. I used the DelimitedSplit8K which you can find in the following article which explains how it works. http://www.sqlservercentral.com/articles/Tally+Table/72993

Here's my option for you that seems to be doing what you need.
CREATE FUNCTION [dbo].[ProperCase]
(
@StrIn VARCHAR(255)
)
RETURNS TABLE WITH SCHEMABINDING
AS
RETURN
SELECT STUFF((SELECT ' ' + UPPER( LEFT( split.Item, 1)) + LOWER(SUBSTRING( split.Item, 2, 255)) word
FROM dbo.DelimitedSplit8K( @StrIn, ' ') split
FOR XML PATH(''),TYPE).value('.', 'varchar(255)'), 1, 1, '') AS ProperCased




Luis C.
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1531651
Posted Thursday, January 16, 2014 9:26 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 3:59 PM
Points: 13,007, Visits: 12,426
Can you post GetNums? There have been a few different proper case functions around here over the years. They are always a challenge because sometime you want every word capitalized and sometimes you want Title Case.

Parade Of The Horribles
Parade of the Horribles

Subtle difference but makes a huge difference.

What about things like Washington D.C.?


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1531652
Posted Thursday, January 16, 2014 9:37 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: 2 days ago @ 4:41 AM
Points: 356, Visits: 2,611
dbo.GetNums is as per below, straight from one of Jeff's discussions/articles I believe:

CREATE FUNCTION [dbo].[GetNums]
(
@low AS BIGINT,
@high AS BIGINT
)
RETURNS TABLE WITH SCHEMABINDING
AS
RETURN
WITH
L0 AS (SELECT c FROM (VALUES(1),(1)) AS D(c)),
L1 AS (SELECT 1 AS c FROM L0 AS A CROSS JOIN L0 AS B),
L2 AS (SELECT 1 AS c FROM L1 AS A CROSS JOIN L1 AS B),
L3 AS (SELECT 1 AS c FROM L2 AS A CROSS JOIN L2 AS B),
L4 AS (SELECT 1 AS c FROM L3 AS A CROSS JOIN L3 AS B),
L5 AS (SELECT 1 AS c FROM L4 AS A CROSS JOIN L4 AS B),
Nums AS (SELECT ROW_NUMBER() OVER(ORDER BY (SELECT NULL)) AS rownum
FROM L5)
SELECT TOP(@high - @low + 1) @low + rownum - 1 AS n
FROM Nums
ORDER BY rownum;

For our purposes capitalising each Letter of a word is acceptable.
Post #1531661
Posted Thursday, January 16, 2014 9:51 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: 2 days ago @ 4:41 AM
Points: 356, Visits: 2,611
Trying to piece together some test data, some Uppercase letters with some spaces inserted:

IF OBJECT_ID('tempdb..#ProperTest','U') IS NOT NULL
DROP TABLE #ProperTest;

SELECT STUFF(STUFF(CHAR(ABS(CHECKSUM(NEWID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEWID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEWID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEWID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEWID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEWID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEWID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEWID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEWID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEWID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEWID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEWID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEWID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEWID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEWID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEWID()))%26+65),N%16+1,1,' '),N%3+1,1,' ') AS String
INTO #ProperTest
FROM dbo.GetNums(1,300000);

Run the Code
PRINT 'Old Method Scalar Function'
SELECT PT.String,
Utility.f_ProperCase(PT.String) AS Proper
FROM #ProperTest AS PT;

PRINT 'Dohsan'
SELECT PT.String,
CA1.ProperCaseString
FROM #ProperTest AS PT
CROSS
APPLY dbo.ProperCase(PT.String) AS CA1;

PRINT 'Luis'
SELECT PT.String,
CA1.ProperCased
FROM #ProperTest AS PT
CROSS
APPLY dbo.ProperCase1(PT.String) AS CA1;

DECLARE @TestVar VARCHAR(16);
DECLARE @StartTime DATETIME;

PRINT 'Old Method Scalar Function'
SELECT @StartTime = GETDATE();

SELECT @TestVar = Utility.f_ProperCase(PT.String)
FROM #ProperTest AS PT;

PRINT CAST(DATEDIFF(ms,@StartTime,GETDATE()) AS VARCHAR) + ' MilliSeconds';

PRINT 'Dohsan'
SELECT @StartTime = GETDATE();

SELECT @TestVar = CA1.ProperCaseString
FROM #ProperTest AS PT
CROSS
APPLY dbo.ProperCase(PT.String) AS CA1;

PRINT CAST(DATEDIFF(ms,@StartTime,GETDATE()) AS VARCHAR) + ' MilliSeconds';

PRINT 'Luis'
SELECT @StartTime = GETDATE();

SELECT @TestVar = CA1.ProperCased
FROM #ProperTest AS PT
CROSS
APPLY dbo.ProperCase1(PT.String) AS CA1;

PRINT CAST(DATEDIFF(ms,@StartTime,GETDATE()) AS VARCHAR) + ' MilliSeconds';

Results:

Old Method Scalar Function
47843 MilliSeconds
Dohsan
18906 MilliSeconds
Luis
4710 MilliSeconds
Post #1531667
Posted Thursday, January 16, 2014 9:55 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 9:48 PM
Points: 3,636, Visits: 8,151
That's nice Dohsan,
Just make sure my function gets the correct results as it won't check for characters different than spaces when trying to capitalize the first letter of each word.



Luis C.
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1531670
Posted Thursday, January 16, 2014 9:57 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: 2 days ago @ 4:41 AM
Points: 356, Visits: 2,611
Yes, I'll have to play around with it a little more when I have some time tomorrow.

I must say i hadn't thought about using the splitter to separate the words out, so +1 for you and ed wagner for having that idea!
Post #1531672
Posted Thursday, January 16, 2014 12:46 PM
SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Today @ 1:48 PM
Points: 4,053, Visits: 3,490
Luis, your function is much simpler than mine was working out to be. I was working on creating a derivative on the DelimitedSplit8K function and was most of the way there, but the presence of multiple trailing spaces was giving me fits during testing. Also, the multiple delimiters were definitely impacting performance.

I like the way you used the unaltered and well-tested function and manipulated the output of it. Mine would have required testing to make sure all bases were covered.



Tally Tables - Performance Personified
String Splitting with True Performance
Best practices on how to ask questions
Post #1531771
« Prev Topic | Next Topic »

Add to briefcase 1234»»»

Permissions Expand / Collapse