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


how to calculate row1 - row2 - row3....


how to calculate row1 - row2 - row3....

Author
Message
sheik
sheik
SSC-Enthusiastic
SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)

Group: General Forum Members
Points: 194 Visits: 101
I have a table which has some n no of rows. The table has Key, value1, value2, value3, etc fields. Now i need to insert a row which should be derived from the existing rows.

eg: below are the data in the table


Key Value1 Value2 Value3
ky010 100 150 90
ky020 150 200 10
ky030 580 400 10
ky040 160 100 10
ky050 110 250 10
ky060 190 280 10
ky070 350 270 10

I need to insert a row as below
ky055 310 50 -10

the Value1, 2 and 3 are derived from the rows ky030 - ky040 - ky050

If it addition i can simply write
SELECT 'ky055', SUM(Value1), SUM(Value2), SUM(Value3)
FROM table_name
WHERE Key in (ky030,ky040,ky050)

but i need to subtract the rows...
Can anyone help me to find a query to generate the value
Ray M
Ray M
SSCertifiable
SSCertifiable (5.2K reputation)SSCertifiable (5.2K reputation)SSCertifiable (5.2K reputation)SSCertifiable (5.2K reputation)SSCertifiable (5.2K reputation)SSCertifiable (5.2K reputation)SSCertifiable (5.2K reputation)SSCertifiable (5.2K reputation)

Group: General Forum Members
Points: 5185 Visits: 1076
Please read this.
http://www.sqlservercentral.com/articles/Best+Practices/61537/

Here is a query that will make THIS specific example work.
It rely's on your Key column to be ordered correctly.
If the order of your keys is guaranteed then fine, but I would seriously look at the design of this table and data storage strategy before worrying about creating these queries.


DECLARE @Table TABLE ([KEY] Varchar(10),Value1 INT, Value2 INT, Value3 INT)

INSERT INTO @Table
SELECT 'ky010', 100, 150, 90 UNION ALL
SELECT 'ky020', 150, 200, 10 UNION ALL
SELECT 'ky030', 580, 400, 10 UNION ALL
SELECT 'ky040', 160, 100, 10 UNION ALL
SELECT 'ky050', 110, 250, 10 UNION ALL
SELECT 'ky060', 190, 280, 10 UNION ALL
SELECT 'ky070', 350, 270, 10

SELECT 'ky055',
SUM(CASE WHEN ID =1 THEN Value1 ELSE Value1 * -1 END),
SUM(CASE WHEN ID =1 THEN Value2 ELSE Value2 * -1 END),
SUM(CASE WHEN ID =1 THEN Value3 ELSE Value3 * -1 END)
FROM (
SELECT RANK() OVER(ORDER BY [Key]) AS id, [Key], Value1, Value2, Value3
FROM @table
WHERE [Key] in ('ky030','ky040','ky050')
)t


sheik
sheik
SSC-Enthusiastic
SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)

Group: General Forum Members
Points: 194 Visits: 101
Thanks Ray,
Its working...
Also the article is nice once. I will follow that....
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