SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Can I Proper case a UK address string with postcode with a function


Can I Proper case a UK address string with postcode with a function

Author
Message
Northern Monkey
Northern Monkey
SSChasing Mays
SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)

Group: General Forum Members
Points: 629 Visits: 421
Hi All

Thanks in advance for any solutions I have been doing some searching and found pattern matching for UK post code but need to find a way to get this to work
Here are some example of the strings

999, Main Road, Some Town, London, NN66 2BN
THE SQUAT, END OF MY ROAD, OTHER PLACE, LONDON, NX1 2BD -- Some with ,

999 Main Road Some Town London NN66 2BN
THE SQUAT END OF MY ROAD OTHER PLACE LONDON NX1 2BD -- Some with no ,

999, Main Road Some Town, London NN66 2BN
THE SQUAT, END OF MY ROAD OTHER PLACE, LONDON, NX1 2BD -- Some with & without and double space or tab,

I need the address string to all be first letter of each word UPPER and rest LOWER except the post code which I need in ALL UPPER please I have tried a few things but no joy sorry to say Sad

And I know having the address in one long string is not the best but this is a DB we have inherited so I have no control

Kind regards
Stig of the dump
sgmunson
sgmunson
SSC Guru
SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)

Group: General Forum Members
Points: 80274 Visits: 6551
Well, if you at least have spaces between each element, you could use a string splitter (see Jeff Moden's article here: http://www.sqlservercentral.com/articles/72993/ ) to get to each element, then as long as an element is not either of the last 2 elements, you UPPER() the leftmost character, and LOWER() the remainder. Otherwise, the last 2 elements are treated to UPPER() in their entirety. Then you reassemble the address using STUFF and FOR XML PATH('') and a space for the separator.

Steve
‌(aka sgmunson)
Smile Smile Smile
Health & Nutrition
Northern Monkey
Northern Monkey
SSChasing Mays
SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)

Group: General Forum Members
Points: 629 Visits: 421
sgmunson - Thursday, July 12, 2018 6:24 AM
Well, if you at least have spaces between each element, you could use a string splitter (see Jeff Moden's article here: http://www.sqlservercentral.com/articles/72993/ ) to get to each element, then as long as an element is not either of the last 2 elements, you UPPER() the leftmost character, and LOWER() the remainder. Otherwise, the last 2 elements are treated to UPPER() in their entirety. Then you reassemble the address using STUFF and FOR XML PATH('') and a space for the separator.

Hi Steve

Thanks for the post I had thought of having to do that but just wanted to know if anyone had found another way

Kind regards
Stig of the dump

sgmunson
sgmunson
SSC Guru
SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)

Group: General Forum Members
Points: 80274 Visits: 6551
Northern Monkey - Thursday, July 12, 2018 7:32 AM
sgmunson - Thursday, July 12, 2018 6:24 AM
Well, if you at least have spaces between each element, you could use a string splitter (see Jeff Moden's article here: http://www.sqlservercentral.com/articles/72993/ ) to get to each element, then as long as an element is not either of the last 2 elements, you UPPER() the leftmost character, and LOWER() the remainder. Otherwise, the last 2 elements are treated to UPPER() in their entirety. Then you reassemble the address using STUFF and FOR XML PATH('') and a space for the separator.

Hi Steve

Thanks for the post I had thought of having to do that but just wanted to know if anyone had found another way

Kind regards
Stig of the dump

Yep. Understand. This is one of those "consequences of bad database design" scenarios. I honestly can't see ANY other way that has a chance at working. At least Jeff's function is lightning fast....


Steve
‌(aka sgmunson)
Smile Smile Smile
Health & Nutrition
ScottPletcher
ScottPletcher
SSC Guru
SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)

Group: General Forum Members
Points: 78184 Visits: 9033
A tightly-written standard scalar function is another option. I'll give you mine. But you'll have to add the UK post code part to it, since this code was not written with that requirement.


SET ANSI_NULLS ON;
SET QUOTED_IDENTIFIER ON;
GO
CREATE FUNCTION [dbo].[Proper_Case] (
@string varchar(2000)
)
RETURNS varchar(2000)
AS
BEGIN /*FUNCTION*/

DECLARE @previousByte int
DECLARE @byte int

SET @string = LOWER(@string)
IF LEFT(@string, 1) LIKE '[a-z]'
SET @string = STUFF(@string, 1, 1, UPPER(LEFT(@string, 1)))
SET @previousByte = 2

WHILE 1 = 1
BEGIN
SET @byte = PATINDEX('%[^a-z0-9][a-z]%', SUBSTRING(@string, @previousByte, 2000))
IF @byte = 0
BREAK
SET @string = STUFF(@string, @previousByte + @byte, 1,
UPPER(SUBSTRING(@string, @previousByte + @byte, 1)))
SET @previousByte = @previousByte + @byte + 1
END /*WHILE*/

RETURN @string

END /*FUNCTION*/



SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
Eirikur Eiriksson
Eirikur Eiriksson
SSC Guru
SSC Guru (148K reputation)SSC Guru (148K reputation)SSC Guru (148K reputation)SSC Guru (148K reputation)SSC Guru (148K reputation)SSC Guru (148K reputation)SSC Guru (148K reputation)SSC Guru (148K reputation)

Group: General Forum Members
Points: 148473 Visits: 22385
Northern Monkey - Thursday, July 12, 2018 4:32 AM
Hi All

Thanks in advance for any solutions I have been doing some searching and found pattern matching for UK post code but need to find a way to get this to work
Here are some example of the strings

999, Main Road, Some Town, London, NN66 2BN
THE SQUAT, END OF MY ROAD, OTHER PLACE, LONDON, NX1 2BD -- Some with ,

999 Main Road Some Town London NN66 2BN
THE SQUAT END OF MY ROAD OTHER PLACE LONDON NX1 2BD -- Some with no ,

999, Main Road Some Town, London NN66 2BN
THE SQUAT, END OF MY ROAD OTHER PLACE, LONDON, NX1 2BD -- Some with & without and double space or tab,

I need the address string to all be first letter of each word UPPER and rest LOWER except the post code which I need in ALL UPPER please I have tried a few things but no joy sorry to say Sad

And I know having the address in one long string is not the best but this is a DB we have inherited so I have no control

Kind regards
Stig of the dump

Quick question, why is the case important, normally one just throws everything in upper or lower case when matching? Are you doing something like a case sensitive edit distance algorithm?
Cool

Another approach could be to normalize the data, plenty of referential data available, makes a set based approach easy.

ScottPletcher
ScottPletcher
SSC Guru
SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)SSC Guru (78K reputation)

Group: General Forum Members
Points: 78184 Visits: 9033
Rather than repeatedly having to identity the post code, add an AFTER INSERT, UPDATE trigger that finds the post code and then store its byte location and length in a column(s). Then you can quickly and easily upper-case the post code after the entire thing has been proper-cased.

SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
edd.parsons
edd.parsons
SSC Journeyman
SSC Journeyman (80 reputation)SSC Journeyman (80 reputation)SSC Journeyman (80 reputation)SSC Journeyman (80 reputation)SSC Journeyman (80 reputation)SSC Journeyman (80 reputation)SSC Journeyman (80 reputation)SSC Journeyman (80 reputation)

Group: General Forum Members
Points: 80 Visits: 154
This is the code we have been using to do this, it's almost certainly not the best way of doing it but it works

DECLARE @Index int,@Char CHAR(1),@InputString VARCHAR(255), @OutputString VARCHAR(255),@postlength int, @postcode char (10)
SET @InputString = 'THE SQUAT, END OF MY ROAD OTHER PLACE, LONDON NX1 2BD'

select @postcode = ltrim(right(rtrim(@InputString),8))
if @postcode <> '' and right(left(@postcode,3),1) not like '[0-9]'
select @postcode = '', @postlength = 0
else if right(left(@postcode,4),1) not like '[0-9]'
select @postlength = 8
else
select @postlength = 9

select @outputstring = LOWER(substring(@InputString,1,len(@InputString)-@postlength))
SET @Index = 2
SET @OutputString = STUFF(@OutputString, 1, 1,UPPER(SUBSTRING(@OutputString,1,1)))

WHILE @Index <= LEN(@InputString)-@postlength
BEGIN
SET @Char = SUBSTRING(@InputString, @Index, 1)
IF @Char IN (' ', ';', ':', '!', '?', ',', '.', '_', '-', '/', '&','''', '(')
IF @Index + 1 <= LEN(@InputString)-@postlength
BEGIN
IF @Char != ''''
SET @OutputString =
STUFF(@OutputString, @Index + 1, 1,UPPER(SUBSTRING(@InputString, @Index + 1, 1)))
END
SET @Index = @Index + 1
END

select locaddress1 =
CASE WHEN @postlength > 0 then
ISNULL(@OutputString+(right(@InputString,@postlength)),'')
ELSE
ISNULL(@OutputString,'')
END
Northern Monkey
Northern Monkey
SSChasing Mays
SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)

Group: General Forum Members
Points: 629 Visits: 421
Thanks for all the reply's I've been fire fighting for the last two days and now playing catch up so I will take a look at the options next week Smile

Many Thanks
S
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum








































































































































































SQLServerCentral


Search