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


Addition Of Digits


Addition Of Digits

Author
Message
J Livingston SQL
J Livingston SQL
Hall of Fame
Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)

Group: General Forum Members
Points: 3445 Visits: 33011
another method here:

http://sqlbump.blogspot.co.uk/2010/06/sum-of-digits-of-number.html

________________________________________________________________
you can lead a user to data....but you cannot make them think
and remember....every day is a school day

SomewhereSomehow
SomewhereSomehow
SSC Journeyman
SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)

Group: General Forum Members
Points: 96 Visits: 469
Cool!!! 4 ways to solve the problem! Definitly all go to my KB.
CELKO's - is the fastest or isn't it? Who will make a proof test?

ps
CELKO,
Are you a Joe Celko, the one, who was the author of marvellous chapter in Itzik Ben Gan book? (Sorry for tactless question).


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
J Livingston SQL
J Livingston SQL
Hall of Fame
Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)

Group: General Forum Members
Points: 3445 Visits: 33011
SomewhereSomehow (8/5/2012)

...Who will make a proof test?



go on...give it a crack:-)

________________________________________________________________
you can lead a user to data....but you cannot make them think
and remember....every day is a school day

SQL Padawan
SQL Padawan
Valued Member
Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)

Group: General Forum Members
Points: 54 Visits: 1162
I could be wrong but Celko's method is the fastest. One thing to keep in mind is the LEN function's limit is 8000 characters or in other words the sum of all digits can not exceed 8000...
Mark Cowne
Mark Cowne
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2090 Visits: 22778
Million row test for three of the solutions. Results are interesting/surpising. Perhaps some of you folks could check this and run it.


--===== Conditionally drop the test table to make reruns in SSMS easier.
-- This is NOT a part of the solution.
IF OBJECT_ID('tempdb..#Test','U') IS NOT NULL
DROP TABLE #Test
;
--===== Create and populate the test table.
-- This is NOT a part of the solution.
SELECT TOP (1000000)
TestID = IDENTITY(INT,1,1),
TestNumber = ABS(CHECKSUM(NEWID()))
INTO #Test
FROM sys.all_columns ac1
CROSS JOIN sys.all_columns ac2
;
--===== Add the expected PK
ALTER TABLE #Test
ADD PRIMARY KEY CLUSTERED (TestID)
;
-----------------------------------------------------------------------------


PRINT '========== SomewhereSomehow ==========================================='
SET STATISTICS TIME ON;
DECLARE @T INT;

with nums(n) as(select n from (values (1),(2),(3),(4),(5),(6),(7),(8),(9),(10))nums(n))
select @T = sum(convert(int,substring(convert(varchar(10),TestNumber),n,1)))
from nums
CROSS JOIN #Test
where n <= len(convert(varchar(10),TestNumber))
GROUP BY TestNumber;

SET STATISTICS TIME OFF;
GO

PRINT '========== CELKO ==========================================='
SET STATISTICS TIME ON;
DECLARE @T INT

SELECT @T = LEN ( REPLACE(REPLACE(REPLACE(REPLACE(REPLACE( REPLACE(REPLACE(REPLACE(REPLACE(REPLACE (CAST (TestNumber AS VARCHAR(150)) ,'0', '') ,'1', '#')
,'2', '##') ,'3', '###') ,'4', '####') ,'5', '#####') ,'6', '######') ,'7', '#######') ,'8', '########') ,'9', '#########'))
FROM #Test;

SET STATISTICS TIME OFF;
GO


PRINT '========== Mark ====================================================='
SET STATISTICS TIME ON;
DECLARE @T INT;

WITH Tens(Pos,Val) AS (
SELECT 1, 1 UNION ALL
SELECT 2, 10 UNION ALL
SELECT 3, 100 UNION ALL
SELECT 4, 1000 UNION ALL
SELECT 5, 10000 UNION ALL
SELECT 6, 100000 UNION ALL
SELECT 7, 1000000 UNION ALL
SELECT 8, 10000000 UNION ALL
SELECT 9, 100000000 UNION ALL
SELECT 10,1000000000)
SELECT @T = SUM((TestNumber / Val) % 10)
FROM Tens
CROSS JOIN #Test
WHERE Val<=TestNumber
GROUP BY TestNumber;

SET STATISTICS TIME OFF;



____________________________________________________

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




Cadavre
Cadavre
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2594 Visits: 8436
Mark-101232 (8/6/2012)
Million row test for three of the solutions. Results are interesting/surpising. Perhaps some of you folks could check this and run it.


Celko forgot to account for the REPLACE "bug".

Change his code to this: -
DECLARE @T INT = 985;

SELECT LEN ( REPLACE(REPLACE(REPLACE(REPLACE(REPLACE( REPLACE(REPLACE(REPLACE(REPLACE(REPLACE (CAST (@T AS VARCHAR(150)) COLLATE Latin1_General_BIN2,'0', '') ,'1', '#')
,'2', '##') ,'3', '###') ,'4', '####') ,'5', '#####') ,'6', '######') ,'7', '#######') ,'8', '########') ,'9', '#########'));



Then take another look at your test results: -
--===== Conditionally drop the test table to make reruns in SSMS easier.
-- This is NOT a part of the solution.
IF OBJECT_ID('tempdb..#Test','U') IS NOT NULL
DROP TABLE #Test
;
--===== Create and populate the test table.
-- This is NOT a part of the solution.
SELECT TOP (1000000)
TestID = IDENTITY(INT,1,1),
TestNumber = ABS(CHECKSUM(NEWID()))
INTO #Test
FROM sys.all_columns ac1
CROSS JOIN sys.all_columns ac2
;
--===== Add the expected PK
ALTER TABLE #Test
ADD PRIMARY KEY CLUSTERED (TestID)
;
-----------------------------------------------------------------------------


PRINT '========== SomewhereSomehow ==========================================='
SET STATISTICS TIME ON;
DECLARE @T INT;

with nums(n) as(select n from (values (1),(2),(3),(4),(5),(6),(7),(8),(9),(10))nums(n))
select @T = sum(convert(int,substring(convert(varchar(10),TestNumber),n,1)))
from nums
CROSS JOIN #Test
where n <= len(convert(varchar(10),TestNumber))
GROUP BY TestNumber;

SET STATISTICS TIME OFF;
GO

PRINT '========== CELKO ==========================================='
SET STATISTICS TIME ON;
DECLARE @T INT

SELECT @T = LEN ( REPLACE(REPLACE(REPLACE(REPLACE(REPLACE( REPLACE(REPLACE(REPLACE(REPLACE(REPLACE (CAST (TestNumber AS VARCHAR(150)) ,'0', '') ,'1', '#')
,'2', '##') ,'3', '###') ,'4', '####') ,'5', '#####') ,'6', '######') ,'7', '#######') ,'8', '########') ,'9', '#########'))
FROM #Test;

SET STATISTICS TIME OFF;
GO


PRINT '========== Mark ====================================================='
SET STATISTICS TIME ON;
DECLARE @T INT;

WITH Tens(Pos,Val) AS (
SELECT 1, 1 UNION ALL
SELECT 2, 10 UNION ALL
SELECT 3, 100 UNION ALL
SELECT 4, 1000 UNION ALL
SELECT 5, 10000 UNION ALL
SELECT 6, 100000 UNION ALL
SELECT 7, 1000000 UNION ALL
SELECT 8, 10000000 UNION ALL
SELECT 9, 100000000 UNION ALL
SELECT 10,1000000000)
SELECT @T = SUM((TestNumber / Val) % 10)
FROM Tens
CROSS JOIN #Test
WHERE Val<=TestNumber
GROUP BY TestNumber;

SET STATISTICS TIME OFF;
GO

PRINT '========== IMPROVED CELKO ==========================================='
SET STATISTICS TIME ON;
DECLARE @T INT;

SELECT @T = LEN ( REPLACE(REPLACE(REPLACE(REPLACE(REPLACE( REPLACE(REPLACE(REPLACE(REPLACE(REPLACE (CAST (TestNumber AS VARCHAR(150)) COLLATE Latin1_General_BIN2,'0', '') ,'1', '#')
,'2', '##') ,'3', '###') ,'4', '####') ,'5', '#####') ,'6', '######') ,'7', '#######') ,'8', '########') ,'9', '#########'))
FROM #Test;

SET STATISTICS TIME OFF;
GO



========== SomewhereSomehow ===========================================

SQL Server Execution Times:
CPU time = 28155 ms, elapsed time = 8756 ms.
========== CELKO ===========================================

SQL Server Execution Times:
CPU time = 24343 ms, elapsed time = 24385 ms.
========== Mark =====================================================

SQL Server Execution Times:
CPU time = 19921 ms, elapsed time = 6877 ms.
========== IMPROVED CELKO ===========================================

SQL Server Execution Times:
CPU time = 3594 ms, elapsed time = 3619 ms.



--edit--
Found the link to the replace "bug"


Forever trying to learn

For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better, quicker answers on SQL Server performance related questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/



If you litter your database queries with nolock query hints, are you aware of the side effects?
Try reading a few of these links...

(*) Missing rows with nolock
(*) Allocation order scans with nolock
(*) Consistency issues with nolock
(*) Transient Corruption Errors in SQL Server error log caused by nolock
(*) Dirty reads, read errors, reading rows twice and missing rows with nolock


Craig Wilkinson - Software Engineer
LinkedIn
Mark Cowne
Mark Cowne
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2090 Visits: 22778
Cadavre (8/6/2012)
Mark-101232 (8/6/2012)
Million row test for three of the solutions. Results are interesting/surpising. Perhaps some of you folks could check this and run it.


Celko forgot to account for the REPLACE "bug".

Change his code to this: -
DECLARE @T INT = 985;

SELECT LEN ( REPLACE(REPLACE(REPLACE(REPLACE(REPLACE( REPLACE(REPLACE(REPLACE(REPLACE(REPLACE (CAST (@T AS VARCHAR(150)) COLLATE Latin1_General_BIN2,'0', '') ,'1', '#')
,'2', '##') ,'3', '###') ,'4', '####') ,'5', '#####') ,'6', '######') ,'7', '#######') ,'8', '########') ,'9', '#########'));



Then take another look at your test results: -
--===== Conditionally drop the test table to make reruns in SSMS easier.
-- This is NOT a part of the solution.
IF OBJECT_ID('tempdb..#Test','U') IS NOT NULL
DROP TABLE #Test
;
--===== Create and populate the test table.
-- This is NOT a part of the solution.
SELECT TOP (1000000)
TestID = IDENTITY(INT,1,1),
TestNumber = ABS(CHECKSUM(NEWID()))
INTO #Test
FROM sys.all_columns ac1
CROSS JOIN sys.all_columns ac2
;
--===== Add the expected PK
ALTER TABLE #Test
ADD PRIMARY KEY CLUSTERED (TestID)
;
-----------------------------------------------------------------------------


PRINT '========== SomewhereSomehow ==========================================='
SET STATISTICS TIME ON;
DECLARE @T INT;

with nums(n) as(select n from (values (1),(2),(3),(4),(5),(6),(7),(8),(9),(10))nums(n))
select @T = sum(convert(int,substring(convert(varchar(10),TestNumber),n,1)))
from nums
CROSS JOIN #Test
where n <= len(convert(varchar(10),TestNumber))
GROUP BY TestNumber;

SET STATISTICS TIME OFF;
GO

PRINT '========== CELKO ==========================================='
SET STATISTICS TIME ON;
DECLARE @T INT

SELECT @T = LEN ( REPLACE(REPLACE(REPLACE(REPLACE(REPLACE( REPLACE(REPLACE(REPLACE(REPLACE(REPLACE (CAST (TestNumber AS VARCHAR(150)) ,'0', '') ,'1', '#')
,'2', '##') ,'3', '###') ,'4', '####') ,'5', '#####') ,'6', '######') ,'7', '#######') ,'8', '########') ,'9', '#########'))
FROM #Test;

SET STATISTICS TIME OFF;
GO


PRINT '========== Mark ====================================================='
SET STATISTICS TIME ON;
DECLARE @T INT;

WITH Tens(Pos,Val) AS (
SELECT 1, 1 UNION ALL
SELECT 2, 10 UNION ALL
SELECT 3, 100 UNION ALL
SELECT 4, 1000 UNION ALL
SELECT 5, 10000 UNION ALL
SELECT 6, 100000 UNION ALL
SELECT 7, 1000000 UNION ALL
SELECT 8, 10000000 UNION ALL
SELECT 9, 100000000 UNION ALL
SELECT 10,1000000000)
SELECT @T = SUM((TestNumber / Val) % 10)
FROM Tens
CROSS JOIN #Test
WHERE Val<=TestNumber
GROUP BY TestNumber;

SET STATISTICS TIME OFF;
GO

PRINT '========== IMPROVED CELKO ==========================================='
SET STATISTICS TIME ON;
DECLARE @T INT;

SELECT @T = LEN ( REPLACE(REPLACE(REPLACE(REPLACE(REPLACE( REPLACE(REPLACE(REPLACE(REPLACE(REPLACE (CAST (TestNumber AS VARCHAR(150)) COLLATE Latin1_General_BIN2,'0', '') ,'1', '#')
,'2', '##') ,'3', '###') ,'4', '####') ,'5', '#####') ,'6', '######') ,'7', '#######') ,'8', '########') ,'9', '#########'))
FROM #Test;

SET STATISTICS TIME OFF;
GO



========== SomewhereSomehow ===========================================

SQL Server Execution Times:
CPU time = 28155 ms, elapsed time = 8756 ms.
========== CELKO ===========================================

SQL Server Execution Times:
CPU time = 24343 ms, elapsed time = 24385 ms.
========== Mark =====================================================

SQL Server Execution Times:
CPU time = 19921 ms, elapsed time = 6877 ms.
========== IMPROVED CELKO ===========================================

SQL Server Execution Times:
CPU time = 3594 ms, elapsed time = 3619 ms.



--edit--
Found the link to the replace "bug"


That explains a lot, thanks!

Also the CELKO solution can be improved a bit by removing the REPLACE(...,'1', '#') - the code is simply counting characters so there's no point changing 1's to #'s.

____________________________________________________

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




Sumit Rastogi
Sumit Rastogi
SSC Rookie
SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)

Group: General Forum Members
Points: 31 Visits: 159
declare @string varchar(max) = '25475675675675675675675675675587876865674553334645647656786867879789780890890789676565674545634343453445675756756786867897978978078997896785657454563445345234534645675678768997807867567456342323167567567567567567567567567567567567567567567665756756756756756756756756756756756756756767876879789797287686782567345345289789797278978978978979245645622222245645622222222435645645645646364564564564564564564564564564564564564564564564562'
declare @s varchar(1)
declare @totalcount int = 0
declare @count int
set @count = LEN(@string)
while (@count != 0)
begin
   set @count = @count - 1
   set @s=convert(int,left(@string, 1))
   set @string = RIGHT(@string, len(@string)-1)
   set @totalcount = @totalcount + @s
end
print convert(varchar,@totalcount)

Thanks,
Sumit Rastogi
SomewhereSomehow
SomewhereSomehow
SSC Journeyman
SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)

Group: General Forum Members
Points: 96 Visits: 469
Cadavre,
Thx for the testing scripts! Especially pointing a bug with replace function (closed as by design).
I have quite similar results

========== SomewhereSomehow ===========================================
SQL Server Execution Times:
CPU time = 19813 ms, elapsed time = 5501 ms.

========== CELKO ===========================================
SQL Server Execution Times:
CPU time = 20437 ms, elapsed time = 20529 ms.

========== Mark =====================================================
SQL Server Execution Times:
CPU time = 12891 ms, elapsed time = 3846 ms.

========== IMPROVED CELKO ===========================================
SQL Server Execution Times:
CPU time = 2859 ms, elapsed time = 2853 ms.




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
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