Tags

, , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , ,


SQL Puzzle | The SUM Puzzle – A SINGLE SELECT

In this puzzle you have to find the sum of val1 and val2 for each group and put that value at the begining of the group in the new column. The challenge here is to do this in a single select. For more details please see the sample input and expected output.

Sample Input

Id Grp Val1 Val2
1 1 30 29
2 1 19 0
3 1 11 45
4 2 0 0
5 2 100 17

Expected Output

Id Grp Val1 Val2 Tot
1 1 30 29 134
2 1 19 0 NULL
3 1 11 45 NULL
4 2 0 0 117
5 2 100 17 NULL

Script – DDL and INSERT Sample Data

--

CREATE TABLE MyData 
(
	 Id INT 
	,Grp INT
	,Val1 INT
	,Val2 INT
)
GO

INSERT INTO MyData VALUES
(1,1,30,29),
(2,1,19,0),
(3,1,11,45),
(4,2,0,0),
(5,2,100,17)
GO

SELECT * FROM MyData
GO

--

SOLUTION 1 | Using PARTITIONS

--


SELECT
   *,IIF(Id = MIN(Id) OVER (PARTITION BY Grp)
		, SUM(Val1) OVER (PARTITION BY Grp) + SUM(Val2) OVER (PARTITION BY Grp)
		,NULL
		) Tot
FROM MyData

--Note that SUM and MIN does not require ORDER BY Clause

--

OUTPUT – 1 | Using PARTITIONS

--

Id          Grp         Val1        Val2        Tot
----------- ----------- ----------- ----------- -----------
1           1           30          29          134
2           1           19          0           NULL
3           1           11          45          NULL
4           2           0           0           117
5           2           100         17          NULL

(5 rows affected)

--

Enjoy 🙂

Please add comment(s) if you have one or multiple solutions in mind. Thank You.

Pawan Khowal

Pawan is a SQL Server Developer. If you need any help in writing code/puzzle or training please email at – pawankkmr”AT”gmail.com. Meanwhile please go throgh the top pages from his blog.

Page Detail URL
☛ SQL Advance Puzzles https://msbiskills.com/tsql-puzzles-asked-in-interview-over-the-years/
☛ SQL Tricky Queries https://msbiskills.com/sql-puzzles-finding-outputs/
☛ SQL Server Perfomance tuning Articles https://msbiskills.com/sql-performance-tuning/
☛ SQL Server Articles https://msbiskills.com/t-sql/
☛ SQL Interview Questions & Answers https://msbiskills.com/sql-server-interview-questions/

My SQL Groups on Facebook:

1. If you like this post, you may want to join my SQL SERVER Interview Puzzles/Interview Questions on Facebook: https://www.facebook.com/groups/1430882120556342/

2. If you like this post, you may want to join my SQL Server Puzzles on Facebook:
https://www.facebook.com/groups/206594023090781/

My SQL Page on Facebook:

2. For all the updates you may follow my page -> https://www.facebook.com/MSBISkillscom-1602779883299222/

Enjoy !!! Keep Learning

Http://MsbiSkills.com