Optimize query needed

  • Hello Expert.

    I need to convert data from an existing column from BigInt to VarBinary type. I wrote the function to do the conversion; the function is fairly fast, however, it is not fast enough to use on a table with more than 40 millions records (takes about 27minutes). Could someone help optimize it so that it runs a bit faster?

    Thanks in advance,

    -Hai

    ALTER function [dbo].[ConvertBigIntToVarBinary]((c)param BigInt)

    returns varbinary(128) AS

    begin

    declare (c)result varchar(128)

    set (c)result = ''

    while 1=1

    begin

    select (c)result= convert(char(1),(c)param % 2)+(c)result, (c)param = convert(bigint, ((c)param / 2))

    if (c)param = 0 return convert(varbinary(128), replace(replace(reverse((c)result),'0','00'),'1','01'),2)

    end

    return convert(varbinary(128),'00',2)

    end

  • Is there a reason why you couldn't just use CAST(SomeBigIntColumn AS VARBINARY(128))?

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Yes there is, if you run the function and pass a parameter like 5, you will see the result. Just perform a normal conversion would not give the desire result

  • Some one suggested this function works

    ALTER function [dbo].[ConvertBigIntToVarBinary1](@param bigint)

    returns varbinary(1000) AS

    begin

    declare @iPower int;

    declare @result varbinary(1000);

    declare @powerOf2 bigint;

    set @result = 0x;

    set @powerOf2 = 1;

    set @iPower = 0;

    while @powerOf2 <= @param

    begin

    set @result = @result + CAST(@param / @powerOf2 % 2 AS binary(1));

    set @iPower = @iPower + 1;

    set @powerOf2 = power(2., @iPower);

    end

    return @result

    end

    Although I dont see much advance of it plus it fails to convert the max bigint value for some reasons

    SELECT dbo.ConvertBigIntToVarBinary1(9223372036854775807)

  • I am seriously missing something:

    SELECT CAST(5 AS VARBINARY(128)) --0x00000005

    SELECT CAST(0x00000005 AS bigint) --5

    SELECT dbo.ConvertBigIntToVarBinary1(5) --0x010001

    SELECT CAST(0x010001 AS bigint) --65537

    Best,
    Kevin G. Boles
    SQL Server Consultant
    SQL MVP 2007-2012
    TheSQLGuru on googles mail service

  • TheSQLGuru (10/2/2012)


    I am seriously missing something:

    SELECT CAST(5 AS VARBINARY(128)) --0x00000005

    SELECT CAST(0x00000005 AS bigint) --5

    SELECT dbo.ConvertBigIntToVarBinary1(5) --0x010001

    SELECT CAST(0x010001 AS bigint) --65537

    NAH! you aren't missing anything. it was just our requirements written that way. In the nutshell, our existing application has capability of searching the varbinary field data bit-by-bit (or byte-by-byte whatever that is..) without first converingt the bit to character, that is from what I was told and understood. so this is the how conversion process works:

    -first convert the bigint to binary value,

    -reverse the entire string

    -foreach bit in the string, add a 0 infront of it.

    -then convert the value to varbinary field using this format: convert(varbinary(128),@result,2)

  • haiao2000 (10/2/2012)


    TheSQLGuru (10/2/2012)


    I am seriously missing something:

    SELECT CAST(5 AS VARBINARY(128)) --0x00000005

    SELECT CAST(0x00000005 AS bigint) --5

    SELECT dbo.ConvertBigIntToVarBinary1(5) --0x010001

    SELECT CAST(0x010001 AS bigint) --65537

    NAH! you aren't missing anything. it was just our requirements written that way. In the nutshell, our existing application has capability of searching the varbinary field data bit-by-bit (or byte-by-byte whatever that is..) without first converingt the bit to character, that is from what I was told and understood. so this is the how conversion process works:

    -first convert the bigint to binary value,

    -reverse the entire string

    -foreach bit in the string, add a 0 infront of it.

    -then convert the value to varbinary field using this format: convert(varbinary(128),@result,2)

    Ahh - what I was missing was the actual requirements! 🙂

    This may get you part-way there: http://pratchev.blogspot.com/2008/04/convert-hex-string-to-binary-string.html. You will need to efficiently deal with leading zeros though before doing the reverse/replace thing. The key is to do this as a set-based operation and not the iterative way you have now. I am confident there is a solution, but it goes beyond what I am willing to invest for free to get you there. 😎

    Best,
    Kevin G. Boles
    SQL Server Consultant
    SQL MVP 2007-2012
    TheSQLGuru on googles mail service

  • Ahh - what I was missing was the actual requirements! 🙂

    This may get you part-way there: http://pratchev.blogspot.com/2008/04/convert-hex-string-to-binary-string.html. You will need to efficiently deal with leading zeros though before doing the reverse/replace thing. The key is to do this as a set-based operation and not the iterative way you have now. I am confident there is a solution, but it goes beyond what I am willing to invest for free to get you there. 😎

    Not big of a deal. Believe it or not...I did this entire thing for free too :-). It wasn't my assignment. Anyway what I got so far should be good for them to start with, they should work on the fine tune it.

    Thanks for direction!

    -Hai

  • I'm not sure how logical this project is, but it seemed interesting to do this without looping. It was fun.

    declare @b-2 bigint = 31;

    declare @out varbinary(128) = 0x;

    -- simple inline tally table

    with cteTen as

    ( select N from (values(1),(1),(1),(1),(1),(1),(1),(1),(1),(1)) as t(N) ),

    cteNums as

    ( select N = 0

    union all

    selecttop (63) -- the 64th bit would be bigger than a bigint max value

    N = row_number() over(order by (select null))

    from cteTen as cte1

    cross join cteTen as cte2 ),

    -- the meat of the query

    cteInit as

    ( selectcte.N

    ,ValThis = power(convert(decimal(20,0), 2), N)

    ,ValNext = power(convert(decimal(20,0), 2), N + 1)

    from cteNums as cte )

    select@out = @out + convert(varbinary(1), case when (@b - (floor(@b / cte.ValNext)) * cte.ValNext) >= cte.ValThis then 1 else 0 end)

    from cteInit as cte

    where cte.ValThis <= @b-2

    order by cte.N desc;

    select @out;

    This is verified to work with the largest possible bigint. I did not code it with negative numbers in mind.

    └> bt



    Forum Etiquette: How to post data/code on a forum to get the best help[/url]

  • bteraberry (10/2/2012)


    I'm not sure how logical this project is, but it seemed interesting to do this without looping. It was fun.

    declare @b-2 bigint = 31;

    declare @out varbinary(128) = 0x;

    -- simple inline tally table

    with cteTen as

    ( select N from (values(1),(1),(1),(1),(1),(1),(1),(1),(1),(1)) as t(N) ),

    cteNums as

    ( select N = 0

    union all

    selecttop (63) -- the 64th bit would be bigger than a bigint max value

    N = row_number() over(order by (select null))

    from cteTen as cte1

    cross join cteTen as cte2 ),

    -- the meat of the query

    cteInit as

    ( selectcte.N

    ,ValThis = power(convert(decimal(20,0), 2), N)

    ,ValNext = power(convert(decimal(20,0), 2), N + 1)

    from cteNums as cte )

    select@out = @out + convert(varbinary(1), case when (@b - (floor(@b / cte.ValNext)) * cte.ValNext) >= cte.ValThis then 1 else 0 end)

    from cteInit as cte

    where cte.ValThis <= @b-2

    order by cte.N desc;

    select @out;

    This is verified to work with the largest possible bigint. I did not code it with negative numbers in mind.

    Wow this is way over my head 🙂 It works, I will runs it against the database and see how faster compare to the original code.

    Thanks for spending time on this. alot to learn from this code. btw, can you help me understand the logics behind this query?

Viewing 10 posts - 1 through 9 (of 9 total)

You must be logged in to reply to this topic. Login to reply