Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Calculate alphabetic sequence


Calculate alphabetic sequence

Author
Message
Lobo Mau
Lobo Mau
SSC Rookie
SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)

Group: General Forum Members
Points: 25 Visits: 26
Comments posted to this topic are about the item Calculate alphabetic sequence
alfonso.pg
alfonso.pg
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 98
The article is lacking in details, examples and explanations...

Of particular interest would be comparing a CLR function's performance to the stored procedure, below, and to a SQL UDF (:sickSmile...

I thought I would add the following info which can be expanded by other SSC members.

The following procedure will convert a bigint value to a customizable Bijective (http://en.wikipedia.org/wiki/Bijective_numeration) value:

CREATE PROCEDURE
base10ToBijectiveBaseX
@input BIGINT
,@digits NVARCHAR( 30 ) = N'ABCDEFGHIJKLMNOPQRSTUVWXYZ'
,@output NVARCHAR( 100 ) = N'' OUTPUT
AS
BEGIN
DECLARE
@length BIGINT
,@remainder BIGINT
;

SELECT
@length = LEN( @digits )
;

WHILE @input > 0
BEGIN
SELECT
@remainder = @input % @length
;

IF @remainder = 0
SELECT
@remainder = @length
;

SELECT
@output = SUBSTRING(
@digits
,@remainder
,1
) + @output

,@input = ( @input - @remainder ) / @length
;

END

-- Include the following lines if you want to output the value as a table value
SELECT
@output
;

END



Execute the proceure using code similar to this:

DECLARE
@converted NVARCHAR( 100 )
,@myValue BIGINT
;

SELECT
@myValue = 220222
;

EXEC base10ToBijectiveBaseX
@input = @myValue
,@output = @converted OUTPUT
;

SELECT
@converted AS convertedValue
;



Or...

DECLARE
@converted NVARCHAR( 100 )
,@myValue BIGINT
;

SELECT
@myValue = 220222
;

EXEC base10ToBijectiveBaseX
@input = @myValue
,@digits = N'AaBbCcXxYyZz'
,@output = @converted OUTPUT
;

SELECT
@converted AS convertedValue
;


I wil omit adding the reverse (BijectiveToBase10) code in hopes of encouraging someone else to participate...
Bill Talada
Bill Talada
Mr or Mrs. 500
Mr or Mrs. 500 (541 reputation)Mr or Mrs. 500 (541 reputation)Mr or Mrs. 500 (541 reputation)Mr or Mrs. 500 (541 reputation)Mr or Mrs. 500 (541 reputation)Mr or Mrs. 500 (541 reputation)Mr or Mrs. 500 (541 reputation)Mr or Mrs. 500 (541 reputation)

Group: General Forum Members
Points: 541 Visits: 1868
Ouch this hurt my brain and took me an hour...but it is slick!
This converts from any base to any base, like hex to decimal or octal.


/*
William Talada
Define baseX and baseY
Pass in a baseX value and it gets converted to baseY
Currently set to convert hex to binary but can handle any imaginary base.
*/

declare
@inA varchar(50),
@baseX varchar(30),
@baseY varchar(30)

set @inA = 'FF';
set @baseX = '0123456789ABCDEF'; -- must always start with zero even if never used (column placeholder for numbers like 20, 130, etc).
set @baseY = '01'; -- must always start with zero even if never used (column placeholder).

declare
@i int,
@in10 int,
@div10 int,
@outB varchar(50),
@RadixA int,
@RadixB int;

set @outB = '';
set @RadixA = len(@baseX);
set @RadixB = len(@baseY);

-- first convert @inA to @in10, base10
set @inA = reverse(@inA);
set @i = 1;
set @in10 = 0;
while @i <= len(@inA)
begin
set @in10 = @in10 + ((charindex(substring(@inA, @i, 1), @baseX) - 1) * power(@radixA, @i-1))
set @i = @i + 1;
end

select @in10;

-- now convert to new base
set @i = 1;
while (@in10 / power(@radixB, @i)) > 0
set @i = @i + 1; -- calculate number of columns needed for destination radix.

set @i = @i - 1; -- overshot so back up.

While @i >= 0
begin
set @div10 = @in10 / power(@radixB, @i); -- get magnitude of left most digit in destination radix.
set @in10 = @in10 - (@div10 * power(@radixB, @i)); -- set remainder

set @outB = @outB + substring(@baseY, @div10+1, 1); -- build output string

set @i = @i - 1 -- calc next lower magnitude
end

select @outB;


Iwas Bornready
Iwas Bornready
SSCrazy Eights
SSCrazy Eights (10K reputation)SSCrazy Eights (10K reputation)SSCrazy Eights (10K reputation)SSCrazy Eights (10K reputation)SSCrazy Eights (10K reputation)SSCrazy Eights (10K reputation)SSCrazy Eights (10K reputation)SSCrazy Eights (10K reputation)

Group: General Forum Members
Points: 9990 Visits: 885
Thanks for the script.
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