I suppose I should explain how this works....
The first thing I do is split the string of characters in to multiple rows. This allows me to easily work on each character separately. To do this, I use a numbers table and the substring function.
First, the numbers table. If you run this in a query window, you will see a simple list of numbers.
Code:
Select Num
From (Select 1 As Num
Union All Select 2
Union All Select 3
Union All Select 4
Union All Select 5
Union All Select 6
Union All Select 7
Union All Select 8
Union All Select 9
Union All Select 10
) As Numbers
I then add in the input variable and use the substring function, like this.
Code:
Declare @Input VarChar(10)
Set @Input = '3589634210'
Select SubString(@Input, Num, 1)
From (Select 1 As Num
Union All Select 2
Union All Select 3
Union All Select 4
Union All Select 5
Union All Select 6
Union All Select 7
Union All Select 8
Union All Select 9
Union All Select 10
) As Numbers
Now, when you run this, you will notice that each character in the string is separated on a different row.
For the next step, we need to realize that each character in the string starts (in the alphabet) 10 positions later than the previous character. Since Num starts at 1, and we want our first position to start at 0, we subtract 1 from num and multiply by 10.
Code:
Select (Num - 1) * 10,
SubString(@Input, Num, 1)
From (Select 1 As Num
Union All Select 2
Union All Select 3
Union All Select 4
Union All Select 5
Union All Select 6
Union All Select 7
Union All Select 8
Union All Select 9
Union All Select 10
) As Numbers
When you run the code above, you will see that the first column in the output is 0, then 10, 20, etc...
Next, we can add the 2 columns together to get the alpha character offset for each input character, like this:
Code:
Declare @Input VarChar(10)
Set @Input = '3589634210'
Select (Num - 1) * 10 + SubString(@Input, Num, 1)
From (Select 1 As Num
Union All Select 2
Union All Select 3
Union All Select 4
Union All Select 5
Union All Select 6
Union All Select 7
Union All Select 8
Union All Select 9
Union All Select 10
) As Numbers
Notice that our alpha character positions exceed the alphabet (26 characters). The next step is to use the MOD function, like this:
Code:
Declare @Input VarChar(10)
Set @Input = '3589634210'
Select ((Num - 1) * 10 + SubString(@Input, Num, 1)) [!]% 26[/!]
From (Select 1 As Num
Union All Select 2
Union All Select 3
Union All Select 4
Union All Select 5
Union All Select 6
Union All Select 7
Union All Select 8
Union All Select 9
Union All Select 10
) As Numbers
This will give us a list of numbers in the range of 0 to 25 corresponding to the position of the letter in the alphabet. The next step is to convert this to the actual letter. 65 is the ASCII number for the letter A. We can add 65 to each number in our list and then convert to ASCII. The CHAR function converts a number to it's ASCII equivalent. Like this:
Code:
Declare @Input VarChar(10)
Set @Input = '3589634210'
Select [!]CHAR(65 + [/!]((Num - 1) * 10 + SubString(@Input, Num, 1)) % 26[!])[/!]
From (Select 1 As Num
Union All Select 2
Union All Select 3
Union All Select 4
Union All Select 5
Union All Select 6
Union All Select 7
Union All Select 8
Union All Select 9
Union All Select 10
) As Numbers
When you run this, you will see that each input character is converted to the appropriate letter. The final step in the process is to concatenate this back in to one string, that's where the FOR XML part comes in.
Code:
Declare @Input VarChar(10)
Set @Input = '3589634210'
Select Convert(VarChar(10),
( Select Char(65 + ((Num - 1) * 10 + SubString(@Input, Num, 1)) % 26)
From (Select 1 As Num
Union All Select 2
Union All Select 3
Union All Select 4
Union All Select 5
Union All Select 6
Union All Select 7
Union All Select 8
Union All Select 9
Union All Select 10
) As Numbers
For XML Path('')
))
This is a relatively complicated process, so I thought a rather lengthy explanation was in order. If you have any questions about this, please let me know.
-George
Microsoft SQL Server MVP
My Blogs
SQLCop
twitter
"The great things about standards is that there are so many to choose from." - Fortune Cookie Wisdom