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


SQL to divide one row by another row based on formula or rule.


SQL to divide one row by another row based on formula or rule.

Author
Message
shashi.bi245
shashi.bi245
SSC-Enthusiastic
SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)

Group: General Forum Members
Points: 179 Visits: 159
Hi All,

I have a below table and need to divide one row by another row based on the formula.

Date Name ID Result
3/18/2013 A 1 5
3/18/2013 B 2 16
3/18/2013 C 3 21
3/18/2013 D 4 11
3/18/2013 E 5 45
3/18/2013 F 6 22
3/18/2013 G 7 5
3/19/2013 A 1 2
3/19/2013 B 2 7
3/19/2013 C 3 15
3/19/2013 D 4 9
3/19/2013 E 5 19
3/19/2013 F 6 12
3/19/2013 G 7 3

Please suggest how to proceed to get below result. Formula Column is used to get Result(%) column.

Formula Date Result(%)
B/A 3/19/2013 0.285714286
D/C 3/19/2013 0.6
F/(E-G) 3/19/2013 0.75
B/A 3/18/2013 0.3125
D/C 3/19/2013 0.523809524
F/(E-G) 3/19/2013 0.55

Thanks in advance.
Lowell
Lowell
SSC Guru
SSC Guru (123K reputation)SSC Guru (123K reputation)SSC Guru (123K reputation)SSC Guru (123K reputation)SSC Guru (123K reputation)SSC Guru (123K reputation)SSC Guru (123K reputation)SSC Guru (123K reputation)

Group: General Forum Members
Points: 123302 Visits: 41447
the OP's data as sample data:
i got that far, but my eyes blurred on the expectations:

With MySampleData (Date, Name, ID, Result )
AS
(
SELECT CONVERT(datetime,'3/18/2013') ,'A',1,5 UNION ALL
SELECT '3/18/2013','B',2,16 UNION ALL
SELECT '3/18/2013','C',3,21 UNION ALL
SELECT '3/18/2013','D',4,11 UNION ALL
SELECT '3/18/2013','E',5,45 UNION ALL
SELECT '3/18/2013','F',6,22 UNION ALL
SELECT '3/18/2013','G',7,5 UNION ALL
SELECT '3/19/2013','A',1,2 UNION ALL
SELECT '3/19/2013','B',2,7 UNION ALL
SELECT '3/19/2013','C',3,15 UNION ALL
SELECT '3/19/2013','D',4,9 UNION ALL
SELECT '3/19/2013','E',5,19 UNION ALL
SELECT '3/19/2013','F',6,12 UNION ALL
SELECT '3/19/2013','G',7,3
)

select * from MySampleData



Lowell
--help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!
Eugene Elutin
Eugene Elutin
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20852 Visits: 5478
Most of OP output results do not match relevant formulas, eg:
B/A 3/19/2013 = 7/ 2 = 3.5 not 0.285714286!

Any way thank's to Lowell for data setup:


declare @MySampleData table (Date datetime, Name char(1), ID int, Result DECIMAL(20,9))
insert @MySampleData
SELECT CONVERT(datetime,'3/18/2013') ,'A',1,5 UNION ALL
SELECT '3/18/2013','B',2,16 UNION ALL
SELECT '3/18/2013','C',3,21 UNION ALL
SELECT '3/18/2013','D',4,11 UNION ALL
SELECT '3/18/2013','E',5,45 UNION ALL
SELECT '3/18/2013','F',6,22 UNION ALL
SELECT '3/18/2013','G',7,5 UNION ALL
SELECT '3/19/2013','A',1,2 UNION ALL
SELECT '3/19/2013','B',2,7 UNION ALL
SELECT '3/19/2013','C',3,15 UNION ALL
SELECT '3/19/2013','D',4,9 UNION ALL
SELECT '3/19/2013','E',5,19 UNION ALL
SELECT '3/19/2013','F',6,12 UNION ALL
SELECT '3/19/2013','G',7,3

;WITH cte_dat
AS
(
SELECT *
,CASE WHEN Name IN ('B','A') THEN 'B/A'
WHEN Name IN ('D','C') THEN 'D/C'
WHEN Name IN ('E','G') THEN 'E-G'
ELSE NULL
END AS Formula
FROM @MySampleData
)
SELECT Formula
,Date
,CASE WHEN Formula = 'B/A' THEN
MAX(CASE WHEN Name = 'B' THEN Result ELSE NULL END)/MAX(CASE WHEN Name = 'A' THEN Result ELSE NULL END)
WHEN Formula = 'D/C' THEN
MAX(CASE WHEN Name = 'D' THEN Result ELSE NULL END)/MAX(CASE WHEN Name = 'C' THEN Result ELSE NULL END)
WHEN Formula = 'E-G' THEN
MAX(CASE WHEN Name = 'E' THEN Result ELSE NULL END)-MAX(CASE WHEN Name = 'G' THEN Result ELSE NULL END)
END AS Result
FROM cte_dat
WHERE Formula IS NOT NULL
GROUP BY Formula, Date
ORDER BY Date, Formula




_____________________________________________
"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
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (150K reputation)SSC Guru (150K reputation)SSC Guru (150K reputation)SSC Guru (150K reputation)SSC Guru (150K reputation)SSC Guru (150K reputation)SSC Guru (150K reputation)SSC Guru (150K reputation)

Group: General Forum Members
Points: 150458 Visits: 39278
Eugene Elutin (3/19/2013)
Most of OP output results do not match relevant formulas, eg:
B/A 3/19/2013 = 7/ 2 = 3.5 not 0.285714286!

Any way thank's to Lowell for data setup:


declare @MySampleData table (Date datetime, Name char(1), ID int, Result DECIMAL(20,9))
insert @MySampleData
SELECT CONVERT(datetime,'3/18/2013') ,'A',1,5 UNION ALL
SELECT '3/18/2013','B',2,16 UNION ALL
SELECT '3/18/2013','C',3,21 UNION ALL
SELECT '3/18/2013','D',4,11 UNION ALL
SELECT '3/18/2013','E',5,45 UNION ALL
SELECT '3/18/2013','F',6,22 UNION ALL
SELECT '3/18/2013','G',7,5 UNION ALL
SELECT '3/19/2013','A',1,2 UNION ALL
SELECT '3/19/2013','B',2,7 UNION ALL
SELECT '3/19/2013','C',3,15 UNION ALL
SELECT '3/19/2013','D',4,9 UNION ALL
SELECT '3/19/2013','E',5,19 UNION ALL
SELECT '3/19/2013','F',6,12 UNION ALL
SELECT '3/19/2013','G',7,3

;WITH cte_dat
AS
(
SELECT *
,CASE WHEN Name IN ('B','A') THEN 'B/A'
WHEN Name IN ('D','C') THEN 'D/C'
WHEN Name IN ('E','G') THEN 'E-G'
ELSE NULL
END AS Formula
FROM @MySampleData
)
SELECT Formula
,Date
,CASE WHEN Formula = 'B/A' THEN
MAX(CASE WHEN Name = 'B' THEN Result ELSE NULL END)/MAX(CASE WHEN Name = 'A' THEN Result ELSE NULL END)
WHEN Formula = 'D/C' THEN
MAX(CASE WHEN Name = 'D' THEN Result ELSE NULL END)/MAX(CASE WHEN Name = 'C' THEN Result ELSE NULL END)
WHEN Formula = 'E-G' THEN
MAX(CASE WHEN Name = 'E' THEN Result ELSE NULL END)-MAX(CASE WHEN Name = 'G' THEN Result ELSE NULL END)
END AS Result
FROM cte_dat
WHERE Formula IS NOT NULL
GROUP BY Formula, Date
ORDER BY Date, Formula





Try flipping the division: 2/7 = 0.2857142857142857.

Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Eugene Elutin
Eugene Elutin
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20852 Visits: 5478
Lynn Pettis (3/19/2013)
Eugene Elutin (3/19/2013)
Most of OP output results do not match relevant formulas, eg:
B/A 3/19/2013 = 7/ 2 = 3.5 not 0.285714286!



Try flipping the division: 2/7 = 0.2857142857142857.


Yep, I know, but then it will be A/B not B/A ;-)

_____________________________________________
"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
shashi.bi245
shashi.bi245
SSC-Enthusiastic
SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)

Group: General Forum Members
Points: 179 Visits: 159
Thanks for the replay.

I am having almost 600 records, so is there any other way to get the result without case statement.
Erin Ramsay
Erin Ramsay
Hall of Fame
Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)

Group: General Forum Members
Points: 3698 Visits: 1126
I'm not sure what the issue is.. it doesn't matter how many records you have when you only have 3 formulae for the case statement. It's not like the case statement is going to grow dependent on your data size.
Eugene Elutin
Eugene Elutin
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20852 Visits: 5478
shashi.bi245 (3/21/2013)
Thanks for the replay.

I am having almost 600 records, so is there any other way to get the result without case statement.


What hardware are you using to run your SQL Server on? ZX Spectrum?
Even this one should process 600 records with no issue.
Seriously, why do you think that CASE WHEN will effect performance?

Or, I guess, you mean something else. Then please provide clear detailed requirements.
Please check the link at the bottom of my signature to find out what really helps to ask your question in a way to attract most relevant and prompt help.

_____________________________________________
"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
shashi.bi245
shashi.bi245
SSC-Enthusiastic
SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)SSC-Enthusiastic (179 reputation)

Group: General Forum Members
Points: 179 Visits: 159
thanks for the clarification. I will try to use this code.
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