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


Addition Of Digits


Addition Of Digits

Author
Message
SomewhereSomehow
SomewhereSomehow
SSC-Enthusiastic
SSC-Enthusiastic (166 reputation)SSC-Enthusiastic (166 reputation)SSC-Enthusiastic (166 reputation)SSC-Enthusiastic (166 reputation)SSC-Enthusiastic (166 reputation)SSC-Enthusiastic (166 reputation)SSC-Enthusiastic (166 reputation)SSC-Enthusiastic (166 reputation)

Group: General Forum Members
Points: 166 Visits: 469
Well, I do all the tests on my local work machine, 3.3GHz-4 core, 3 GB RAM. SQL Server 2008R2 RTM.

I have quite the same performance and the same plans for both queries - with cross apply values and without cross apply. Smart optimizer tranformes it in the same way.


I am really sorry for my poor gramma. And I hope that value of my answers will outweigh the harm for your eyes.
Blog: http://somewheresomehow.ru
Twitter: @SomewereSomehow
Paul White
Paul White
SSCoach
SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)

Group: General Forum Members
Points: 15600 Visits: 11355
This is about twice as fast for me:


CREATE ASSEMBLY Test
FROM 0x4D5A90000300000004000000FFFF0000B800000000000000400000000000000000000000000000000000000000000000000000000000000000000000800000000E1FBA0E00B409CD21B8014CCD21546869732070726F6772616D2063616E6E6F742062652072756E20696E20444F53206D6F64652E0D0D0A2400000000000000504500004C010300453D5C500000000000000000E00002210B010800000800000006000000000000FE250000002000000040000000004000002000000002000004000000000000000400000000000000008000000002000000000000030040850000100000100000000010000010000000000000100000000000000000000000B02500004B00000000400000A802000000000000000000000000000000000000006000000C000000142500001C0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000200000080000000000000000000000082000004800000000000000000000002E7465787400000004060000002000000008000000020000000000000000000000000000200000602E72737263000000A80200000040000000040000000A0000000000000000000000000000400000402E72656C6F6300000C0000000060000000020000000E00000000000000000000000000004000004200000000000000000000000000000000E025000000000000480000000200050084200000900400000100000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000133003001D00000001000011160A02280500000A0B2B0C06071F0A5D580A071F0A5B0B071630F0062A1E02280600000A2A00000042534A4201000100000000000C00000076322E302E35303732370000000005006C00000030010000237E00009C0100004001000023537472696E677300000000DC0200000800000023555300E4020000100000002347554944000000F40200009C01000023426C6F620000000000000002000001471502000900000000FA2533001600000100000007000000020000000200000001000000060000000400000001000000010000000200000000000A0001000000000006003D00360006006D005A000B00810000000600B00090000600D00090000A001F01040106003401360000000000010000000000010001000100100018000000050001000100502000000000960044000A00010079200000000086184E000F00020000000100540011004E00130021004E00190029004E000F0031004E000F00390039010A0009004E000F00200023001E002E000B006B012E00130074012E001B007D016601048000000000000000000000000000000000EE00000002000000000000000000000001002D00000000000200000000000000000000000100F800000000000000003C4D6F64756C653E004461746162617365332E646C6C0055736572446566696E656446756E6374696F6E73006D73636F726C69620053797374656D004F626A6563740053756D446967697473002E63746F7200496E7075740053797374656D2E446961676E6F73746963730044656275676761626C6541747472696275746500446562756767696E674D6F6465730053797374656D2E52756E74696D652E436F6D70696C6572536572766963657300436F6D70696C6174696F6E52656C61786174696F6E734174747269627574650052756E74696D65436F6D7061746962696C697479417474726962757465004461746162617365330053797374656D2E44617461004D6963726F736F66742E53716C5365727665722E5365727665720053716C46756E6374696F6E417474726962757465004D61746800416273000000000003200000000000E371327B18D8AB49BF080585140503AB0008B77A5C561934E08904000108080320000105200101110D04200101088146010004005455794D6963726F736F66742E53716C5365727665722E5365727665722E446174614163636573734B696E642C2053797374656D2E446174612C2056657273696F6E3D322E302E302E302C2043756C747572653D6E65757472616C2C205075626C69634B6579546F6B656E3D623737613563353631393334653038390A446174614163636573730000000054557F4D6963726F736F66742E53716C5365727665722E5365727665722E53797374656D446174614163636573734B696E642C2053797374656D2E446174612C2056657273696F6E3D322E302E302E302C2043756C747572653D6E65757472616C2C205075626C69634B6579546F6B656E3D623737613563353631393334653038391053797374656D446174614163636573730000000054020F497344657465726D696E6973746963015402094973507265636973650104070208080801000200000000000801000800000000001E01000100540216577261704E6F6E457863657074696F6E5468726F77730100000000453D5C50000000000200000080000000302500003007000052534453FA3B49E3B829D24C859CA14C76F908B101000000633A5C55736572735C5061756C2057686974655C446F63756D656E74735C56697375616C2053747564696F20323031305C50726F6A656374735C4461746162617365335C4461746162617365335C6F626A5C52656C656173655C4461746162617365332E70646200D82500000000000000000000EE250000002000000000000000000000000000000000000000000000E02500000000000000005F436F72446C6C4D61696E006D73636F7265652E646C6C0000000000FF250020400000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000001001000000018000080000000000000000000000000000001000100000030000080000000000000000000000000000001000000000048000000584000004C02000000000000000000004C0234000000560053005F00560045005200530049004F004E005F0049004E0046004F0000000000BD04EFFE00000100000000000000000000000000000000003F000000000000000400000002000000000000000000000000000000440000000100560061007200460069006C00650049006E0066006F00000000002400040000005400720061006E0073006C006100740069006F006E00000000000000B004AC010000010053007400720069006E006700460069006C00650049006E0066006F0000008801000001003000300030003000300034006200300000002C0002000100460069006C0065004400650073006300720069007000740069006F006E000000000020000000300008000100460069006C006500560065007200730069006F006E000000000030002E0030002E0030002E00300000003C000E00010049006E007400650072006E0061006C004E0061006D00650000004400610074006100620061007300650033002E0064006C006C0000002800020001004C006500670061006C0043006F00700079007200690067006800740000002000000044000E0001004F0072006900670069006E0061006C00460069006C0065006E0061006D00650000004400610074006100620061007300650033002E0064006C006C000000340008000100500072006F006400750063007400560065007200730069006F006E00000030002E0030002E0030002E003000000038000800010041007300730065006D0062006C0079002000560065007200730069006F006E00000030002E0030002E0030002E0030000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000002000000C000000003600000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000
WITH PERMISSION_SET = SAFE;
GO
CREATE FUNCTION dbo.SumDigits
(@Input integer)
RETURNS integer
AS EXTERNAL NAME Test.UserDefinedFunctions.SumDigits;
GO
-- Test & ensure function is fully compiled
SELECT dbo.SumDigits (2147483647);


SET STATISTICS TIME ON;
DECLARE @T INT;

SELECT @T = dbo.SumDigits(TestNumber)
FROM #Test;

SET STATISTICS TIME OFF;



Source:

    public static int SumDigits(int Input)
    
{
        
int sum = 0;
        
for (int n = System.Math.Abs(Input); n > 0; sum += n % 10, n /= 10) ;
        
return sum;
    
}





Paul White
SQLPerformance.com
SQLblog.com
@SQL_Kiwi
Eugene Elutin
Eugene Elutin
SSCarpal Tunnel
SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)

Group: General Forum Members
Points: 4968 Visits: 5478
SQL Kiwi (9/21/2012)
This is about twice as fast for me:
...


public static int SumDigits(int Input)
{
int sum = 0;
for (int n = System.Math.Abs(Input); n > 0; sum += n % 10, n /= 10) ;
return sum;
}



...


Another way in c# :



public static int SumDigits(int Input) { return Input.ToString().Sum(c => c - '0'); }




_____________________________________________
"The only true wisdom is in knowing you know nothing"
"O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
Paul White
Paul White
SSCoach
SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)

Group: General Forum Members
Points: 15600 Visits: 11355
Eugene Elutin (9/21/2012)
Another way in c# :


public static int SumDigits(int Input) { return Input.ToString().Sum(c => c - '0'); }


I think that would be slower (and it also requires a higher version of .NET - the function I posted works on SQL Server 2005-2012).



Paul White
SQLPerformance.com
SQLblog.com
@SQL_Kiwi
CapnHector
CapnHector
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1331 Visits: 1789
glad im starting to learn c#. i knew deep down that c# was the way to go but this simiple example shows me im right.


For faster help in answering any problems Please read How to post data/code on a forum to get the best help - Jeff Moden for the best way to ask your question.

For performance Issues see how we like them posted here: How to Post Performance Problems - Gail Shaw

Need to Split some strings? Jeff Moden's DelimitedSplit8K
Jeff Moden's Cross tab and Pivots Part 1
Jeff Moden's Cross tab and Pivots Part 2
Mark Cowne
Mark Cowne
Hall of Fame
Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)

Group: General Forum Members
Points: 3097 Visits: 24063
SQL Kiwi (9/21/2012)
This is about twice as fast for me:

Source:

    public static int SumDigits(int Input)
    
{
        
int sum = 0;
        
for (int n = System.Math.Abs(Input); n > 0; sum += n % 10, n /= 10) ;
        
return sum;
    
}




Unrolling the loop yields a small performance gain. Still doesn't handle NULLs or -2147483648 though.


    [Microsoft.SqlServer.Server.SqlFunction]
public static int SumDigits(int Input)
{
int n = (Input >= 0 ? Input : -Input);
return (n % 10) +
((n/10) % 10) +
((n/100) % 10) +
((n/1000) % 10) +
((n/10000) % 10) +
((n/100000) % 10) +
((n/1000000) % 10) +
((n/10000000) % 10) +
((n/100000000) % 10) +
((n/1000000000) % 10);
}



____________________________________________________

Deja View - The strange feeling that somewhere, sometime you've optimised this query before

How to get the best help on a forum

http://www.sqlservercentral.com/articles/Best+Practices/61537




Paul White
Paul White
SSCoach
SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)

Group: General Forum Members
Points: 15600 Visits: 11355
Mark-101232 (9/24/2012)
Unrolling the loop yields a small performance gain. Still doesn't handle NULLs or -2147483648 though.

Unrolling the loop is an interesting idea, I will have a play with that in a minute to see if it works the same for me. I think I prefer the loop though - it's neater to my mind.

Handling NULL and -2147483648 is another good point (though the original test rig can produce neither value, in my defence).
The point I was looking to make is that expression evaluation in T-SQL is interpreted and therefore quite slow.
It is amazing that passing a value out to CLR and back is faster, even without working hard to find an optimal .NET algorithm.
Anyway, updated code to handle all values and NULL below:


CREATE ASSEMBLY Test
FROM 0x4D5A90000300000004000000FFFF0000B800000000000000400000000000000000000000000000000000000000000000000000000000000000000000800000000E1FBA0E00B409CD21B8014CCD21546869732070726F6772616D2063616E6E6F742062652072756E20696E20444F53206D6F64652E0D0D0A2400000000000000504500004C010300274C60500000000000000000E00002210B0108000008000000060000000000006E2600000020000000400000000040000020000000020000040000000000000004000000000000000080000000020000000000000300408500001000001000000000100000100000000000001000000000000000000000001C2600004F00000000400000A802000000000000000000000000000000000000006000000C000000802500001C0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000200000080000000000000000000000082000004800000000000000000000002E7465787400000074060000002000000008000000020000000000000000000000000000200000602E72737263000000A80200000040000000040000000A0000000000000000000000000000400000402E72656C6F6300000C0000000060000000020000000E0000000000000000000000000000400000420000000000000000000000000000000050260000000000004800000002000500A0200000E004000001000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000001330030039000000010000110F00280500000A2C067E0600000A2A160A0F00280700000A0B2B0C06071F0A5D580A071F0A5B0B072DF106162F0406652B0106730800000A2A1E02280900000A2A00000042534A4201000100000000000C00000076322E302E35303732370000000005006C00000044010000237E0000B00100006C01000023537472696E6773000000001C03000008000000235553002403000010000000234755494400000034030000AC01000023426C6F620000000000000002000001471502000900000000FA2533001600000100000007000000020000000200000001000000090000000400000001000000010000000200000000000A0001000000000006003D0036000A00650050000600970084000F00AB0000000600DA00BA000600FA00BA000A003D0122010000000001000000000001000100010010001800000005000100010050200000000096006E000A0001009520000000008618780011000200000001007E00190078001500290078001B0031007800110039007800110011005201680111005D016C01110062017001110078001B000900780011002000230020002E000B0079012E00130082012E001B008B0174010480000000000000000000000000000000001801000002000000000000000000000001002D0000000000020000000000000000000000010044000000000000000000003C4D6F64756C653E004461746162617365332E646C6C0055736572446566696E656446756E6374696F6E73006D73636F726C69620053797374656D004F626A6563740053797374656D2E446174610053797374656D2E446174612E53716C54797065730053716C496E7433320053756D446967697473002E63746F7200496E7075740053797374656D2E446961676E6F73746963730044656275676761626C6541747472696275746500446562756767696E674D6F6465730053797374656D2E52756E74696D652E436F6D70696C6572536572766963657300436F6D70696C6174696F6E52656C61786174696F6E734174747269627574650052756E74696D65436F6D7061746962696C69747941747472696275746500446174616261736533004D6963726F736F66742E53716C5365727665722E5365727665720053716C46756E6374696F6E417474726962757465006765745F49734E756C6C004E756C6C006765745F56616C7565000003200000000000E58AE8812A08674882CB590B906DDF360008B77A5C561934E089060001110911090320000105200101111104200101088146010004005455794D6963726F736F66742E53716C5365727665722E5365727665722E446174614163636573734B696E642C2053797374656D2E446174612C2056657273696F6E3D322E302E302E302C2043756C747572653D6E65757472616C2C205075626C69634B6579546F6B656E3D623737613563353631393334653038390A446174614163636573730000000054557F4D6963726F736F66742E53716C5365727665722E5365727665722E53797374656D446174614163636573734B696E642C2053797374656D2E446174612C2056657273696F6E3D322E302E302E302C2043756C747572653D6E65757472616C2C205075626C69634B6579546F6B656E3D623737613563353631393334653038391053797374656D446174614163636573730000000054020F497344657465726D696E6973746963015402094973507265636973650103200002030611090320000804070208080801000200000000000801000800000000001E01000100540216577261704E6F6E457863657074696F6E5468726F777301000000000000274C60500000000002000000800000009C2500009C07000052534453FA3B49E3B829D24C859CA14C76F908B103000000633A5C55736572735C5061756C2057686974655C446F63756D656E74735C56697375616C2053747564696F20323031305C50726F6A656374735C4461746162617365335C4461746162617365335C6F626A5C52656C656173655C4461746162617365332E706462004426000000000000000000005E26000000200000000000000000000000000000000000000000000050260000000000000000000000005F436F72446C6C4D61696E006D73636F7265652E646C6C0000000000FF2500204000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000001001000000018000080000000000000000000000000000001000100000030000080000000000000000000000000000001000000000048000000584000004C02000000000000000000004C0234000000560053005F00560045005200530049004F004E005F0049004E0046004F0000000000BD04EFFE00000100000000000000000000000000000000003F000000000000000400000002000000000000000000000000000000440000000100560061007200460069006C00650049006E0066006F00000000002400040000005400720061006E0073006C006100740069006F006E00000000000000B004AC010000010053007400720069006E006700460069006C00650049006E0066006F0000008801000001003000300030003000300034006200300000002C0002000100460069006C0065004400650073006300720069007000740069006F006E000000000020000000300008000100460069006C006500560065007200730069006F006E000000000030002E0030002E0030002E00300000003C000E00010049006E007400650072006E0061006C004E0061006D00650000004400610074006100620061007300650033002E0064006C006C0000002800020001004C006500670061006C0043006F00700079007200690067006800740000002000000044000E0001004F0072006900670069006E0061006C00460069006C0065006E0061006D00650000004400610074006100620061007300650033002E0064006C006C000000340008000100500072006F006400750063007400560065007200730069006F006E00000030002E0030002E0030002E003000000038000800010041007300730065006D0062006C0079002000560065007200730069006F006E00000030002E0030002E0030002E0030000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000002000000C000000703600000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000
WITH PERMISSION_SET = SAFE;
GO
CREATE FUNCTION dbo.SumDigits
(@Input integer)
RETURNS integer
AS EXTERNAL NAME Test.UserDefinedFunctions.SumDigits;



Source:

public static SqlInt32 SumDigits(SqlInt32 Input)
{
    
if (Input.IsNull)
    
{
        
return SqlInt32.Null;
    
}

    
int sum = 0;
    
for (int n = Input.Value; n != 0; sum += n % 10, n /= 10) ;
    
return new SqlInt32(sum >= 0 ? sum : -sum);
}




Paul White
SQLPerformance.com
SQLblog.com
@SQL_Kiwi
Mark Cowne
Mark Cowne
Hall of Fame
Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)

Group: General Forum Members
Points: 3097 Visits: 24063
SQL Kiwi (9/24/2012)



Handling NULL and -2147483648 is another good point (though the original test rig can produce neither value, in my defence).



NULL can also be handled by adding 'RETURNS NULL ON NULL INPUT' to the wrapper.

____________________________________________________

Deja View - The strange feeling that somewhere, sometime you've optimised this query before

How to get the best help on a forum

http://www.sqlservercentral.com/articles/Best+Practices/61537




Paul White
Paul White
SSCoach
SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)

Group: General Forum Members
Points: 15600 Visits: 11355
Mark-101232 (9/24/2012)
NULL can also be handled by adding 'RETURNS NULL ON NULL INPUT' to the wrapper.

Yes that is true.
I did wonder about asking what should be returned for NULL input.
Some might prefer a zero return value - I didn't want to assume.
Adding the RETURNS thing does prevent the function being called which is nice.
That reminds me of a very welcome addition to SQL Server 2012: deterministic SQLCLR scalar functions can be constant-folded!



Paul White
SQLPerformance.com
SQLblog.com
@SQL_Kiwi
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