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 Thursday, August 2, 2012 11:42 PM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Today @ 6:58 AM
Points: 255, Visits: 619
Hi,
This was the question ask to one of my friend during an interview. He was ask to perform the addition of the digits.
Suppose the number is 985 the output would be 22(9+8+5).
Post #1339633
Posted Friday, August 3, 2012 12:22 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
Here is my solution
declare @i int = 985;

with nums(n) as(select n from (values (1),(2),(3),(4),(5),(6),(7),(8),(9),(10))nums(n))
select sum(convert(int,substring(convert(varchar(10),@i),n,1)))
from nums where n <= len(convert(varchar(10),@i))




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 #1339641
Posted Friday, August 3, 2012 7:24 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Today @ 6:58 AM
Points: 255, Visits: 619
Thanks that help
Post #1339813
Posted Friday, August 3, 2012 2:43 PM


Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Yesterday @ 8:18 AM
Points: 562, Visits: 2,617
SomewhereSomehow (8/3/2012)
Here is my solution
declare @i int = 985;

with nums(n) as(select n from (values (1),(2),(3),(4),(5),(6),(7),(8),(9),(10))nums(n))
select sum(convert(int,substring(convert(varchar(10),@i),n,1)))
from nums where n <= len(convert(varchar(10),@i))



This is good. A couple things to note:
First, the length of the input variable (@i) is limited to the size of the two varchar declarations. For example, say @i = 99999999999 (that's eleven 9's), you would get an overflow error when converting the expression to varchar...

No big deal; who cares?... Just change the varchars to varchar(20) or varchar(50) and declare @i as bigint. There. Problem solved!!!

Nope. Still have one thing to address and this [b]WILL NOT produce an error[/b]. Instead you will just an incorrect aggregation. For the agregation to be accurate you would have to add additional values to your CTE. Again, say @i = 99999999999 (11 9's) you would return a 90(incorrect) instead of 99(correct). To fix this you would have to add an (11). If @i was 20 characters long you would have to add (11),(12)...(20).

A better way to write this would be:

DECLARE @i BIGINT=99999999999;

with nums(n) as
(
SELECT 1
UNION ALL
SELECT n+1 FROM nums WHERE n<30
)
select sum(convert(int,substring(convert(varchar(30),@i),n,1)))
from nums where n <= len(convert(varchar(30),@i));

Now @i can be 18 characters long (limited to 18 because of the bigint). How about we change @i to varchar(50). Now it works for a number that's 50 chars long.


Instead of:
select n from (values (1),(2),(3),(4)...(50))nums(n)

We are using some recursion:
with nums(n) as
(
SELECT 1
UNION ALL
SELECT n+1 FROM nums WHERE n<LEN(@i)
)

... and then we pull it all together:
DECLARE @i varchar(50)='99999999999999999999999999999999999999999999999999';

with nums(n) as
(
SELECT 1
UNION ALL
SELECT n+1 FROM nums WHERE n<LEN(@i)
)
select sum(convert(int,substring(convert(varchar(50),@i),n,1)))
from nums where n <= len(convert(varchar(50),@i));
GO



-- Alan Burstein



Read this article for best practices on asking questions.
Need to split a string? Try this (Jeff Moden)
Need a pattern-based string spitter? Try this (Dwain Camps)
My blog
Post #1340116
Posted Friday, August 3, 2012 2:59 PM


Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Yesterday @ 8:18 AM
Points: 562, Visits: 2,617
Here is my solution:

DECLARE @i varchar(50)='122333444455555';

WITH val(x,n) AS
(
SELECT LEFT(@i,LEN(@i)),'0'
UNION ALL
SELECT LEFT(x,LEN(x)-1),RIGHT(x,1) FROM val WHERE LEN(x)>0
)
SELECT SUM(CAST(n AS int)) FROM val

What's cool is you can replace
SELECT SUM(CAST(n AS int)) FROM val 

with
SELECT * FROM val 

to see how it works.

Result set:
x                                                  n
-------------------------------------------------- ----
122333444455555 0
12233344445555 5
1223334444555 5
122333444455 5
12233344445 5
1223334444 5
122333444 4
12233344 4
1223334 4
122333 4
12233 3
1223 3
122 3
12 2
1 2
1



-- Alan Burstein



Read this article for best practices on asking questions.
Need to split a string? Try this (Jeff Moden)
Need a pattern-based string spitter? Try this (Dwain Camps)
My blog
Post #1340118
Posted Friday, August 3, 2012 3:32 PM
Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 3:21 PM
Points: 3,135, Visits: 11,471
A little dynamic SQL with a string of 100 digits as input:


declare @val varchar(100) =
'20876543914578560430730723092317208765439145785604'+
'3073072309231720876543914578560430730723092317208'

declare @cmd varchar(300)

set @cmd = 'select [Sum] = '+
reverse(substring(reverse(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(
convert(varchar(300),@val),'9','9+'),'8','8+'),'7','7+'),'6','6+')
,'5','5+'),'4','4+'),'3','3+'),'2','2+'),'1','1+'),'0','0+')),2,300))

print '@val = '+@val
print '@cmd = '+@cmd

exec (@cmd)


Results:

@val = 208765439145785604307307230923172087654391457856043073072309231720876543914578560430730723092317208
@cmd = select [Sum] = 2+0+8+7+6+5+4+3+9+1+4+5+7+8+5+6+0+4+3+0+7+3+0+7+2+3+0+9+2+3+1+7+2+0+8+7+6+5+4+3+9+1+4+5+7+8+5+6+0+4+3+0+7+3+0+7+2+3+0+9+2+3+1+7+2+0+8+7+6+5+4+3+9+1+4+5+7+8+5+6+0+4+3+0+7+3+0+7+2+3+0+9+2+3+1+7+2+0+8
Sum
-----------
403

(1 row(s) affected)

Post #1340131
Posted Saturday, August 4, 2012 12:10 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
XMLSQLNinja,
Using the same logic. Yor solution will not work if there will be 51 digits.
Try to understand - my solution was intended to work only with int (and 999 999 999 99 is not int) in the same way, as yours only with 50 digits (btw, why 50, not 49 or 53?).
And one note, specifying input as string - not good idea imho, it coul be easily broken if there will be not a digit char in the string. If we talk about numbers, the input should be only one of numeric types - this is good form.



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 #1340165
Posted Saturday, August 4, 2012 4:48 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 7:00 AM
Points: 1,945, Visits: 2,884
http://beyondrelational.com/modules/2/blogs/70/posts/14472/sum-up-digits-of-a-number.aspx

We can just convert each digit into a hash mark. Concatenate them and measure the length. This is pure ANSI/ISO Standard SQL without any XML or other foreign language contamenation.

SET @digits_sum = LEN ( REPLACE(REPLACE(REPLACE(REPLACE(REPLACE( REPLACE(REPLACE(REPLACE(REPLACE(REPLACE (CAST (@in_integer AS VARCHAR(150)) ,'0', '') ,'1', '#') ,'2', '##') ,'3', '###') ,'4', '####') ,'5', '#####') ,'6', '######') ,'7', '#######') ,'8', '########') ,'9', '#########'));




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 #1340226
Posted Sunday, August 5, 2012 1:54 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
CELKO,
Good idea, interesting approach! Smth tell's me that it would be also the fastest way of doing this!



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 #1340246
Posted Sunday, August 5, 2012 3:34 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, April 8, 2014 6:13 AM
Points: 1,694, Visits: 19,550
Another way, up to BIGINTs only

DECLARE @num BIGINT = 985;

WITH Tens(Pos,Val) AS (
SELECT 1, CAST(1 AS BIGINT) UNION ALL
SELECT 2, CAST(10 AS BIGINT) UNION ALL
SELECT 3, CAST(100 AS BIGINT) UNION ALL
SELECT 4, CAST(1000 AS BIGINT) UNION ALL
SELECT 5, CAST(10000 AS BIGINT) UNION ALL
SELECT 6, CAST(100000 AS BIGINT) UNION ALL
SELECT 7, CAST(1000000 AS BIGINT) UNION ALL
SELECT 8, CAST(10000000 AS BIGINT) UNION ALL
SELECT 9, CAST(100000000 AS BIGINT) UNION ALL
SELECT 10,CAST(1000000000 AS BIGINT) UNION ALL
SELECT 11,CAST(10000000000 AS BIGINT) UNION ALL
SELECT 12,CAST(100000000000 AS BIGINT) UNION ALL
SELECT 13,CAST(1000000000000 AS BIGINT) UNION ALL
SELECT 14,CAST(10000000000000 AS BIGINT) UNION ALL
SELECT 15,CAST(100000000000000 AS BIGINT) UNION ALL
SELECT 16,CAST(1000000000000000 AS BIGINT) UNION ALL
SELECT 17,CAST(10000000000000000 AS BIGINT) UNION ALL
SELECT 18,CAST(100000000000000000 AS BIGINT) UNION ALL
SELECT 19,CAST(1000000000000000000 AS BIGINT))
SELECT SUM((@num / Val) % 10)
FROM Tens
WHERE Val<=@num;



____________________________________________________

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 #1340255
« Prev Topic | Next Topic »

Add to briefcase 12345»»»

Permissions Expand / Collapse