Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««12345»»»

Addition Of Digits Expand / Collapse
Author
Message
Posted Sunday, August 5, 2012 5:10 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 10:05 AM
Points: 1,886, Visits: 18,560
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 !
__________________________________________________________________
Post #1340257
Posted Sunday, August 5, 2012 8:33 AM


SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Friday, June 27, 2014 4:17 AM
Points: 75, Visits: 443
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
Post #1340276
Posted Sunday, August 5, 2012 9:04 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 10:05 AM
Points: 1,886, Visits: 18,560
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 !
__________________________________________________________________
Post #1340278
Posted Sunday, August 5, 2012 1:36 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, July 23, 2014 3:32 PM
Points: 44, Visits: 1,066
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...
Post #1340289
Posted Sunday, August 5, 2012 6:44 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 7:55 AM
Points: 1,945, Visits: 2,863
SomewhereSomehow (8/5/2012)
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?


That link I gave to the blog has even more. I would suspect I have the fastest because (1) it is pure SQL which is faster than jumping outside and back again (2) it is pure nested function calls, so it is done on a stack or other bit of hardware without disk access.

Inspiration is from a SESAME STREET episode where penguins are ordering fish at a hotel without numbers.

[/quote]
Are you a Joe Celko, the one, who was the author of marvelous` chapter in Itzik Ben Gan book? (Sorry for tactless question).


Gee, I like to think of myself as the author of marvelous books of his own, but yes. I have used a lot fo Ben Gan material over the years.


Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1340319
Posted Monday, August 6, 2012 3:10 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, April 8, 2014 6:13 AM
Points: 1,694, Visits: 19,550
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;



____________________________________________________

How to get the best help on a forum

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

Never approach a goat from the front, a horse from the rear, or a fool from any direction.
Post #1340439
Posted Monday, August 6, 2012 3:41 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 8:47 AM
Points: 2,422, Visits: 7,443
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"



Not a DBA, just 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


LinkedIn | Blog coming soon (for sufficiently large values of "soon" )!
Post #1340465
Posted Monday, August 6, 2012 3:50 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, April 8, 2014 6:13 AM
Points: 1,694, Visits: 19,550
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.



____________________________________________________

How to get the best help on a forum

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

Never approach a goat from the front, a horse from the rear, or a fool from any direction.
Post #1340471
Posted Monday, August 6, 2012 3:51 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Thursday, March 27, 2014 12:42 AM
Points: 24, Visits: 116
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
Post #1340472
Posted Monday, August 6, 2012 4:18 AM


SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Friday, June 27, 2014 4:17 AM
Points: 75, Visits: 443
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
Post #1340496
« Prev Topic | Next Topic »

Add to briefcase ««12345»»»

Permissions Expand / Collapse