SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 SQL Server 2000 Forums
 Transact-SQL (2000)
 Update field with aggregate value?
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

t1g312
Posting Yak Master

United Arab Emirates
148 Posts

Posted - 03/01/2006 :  01:02:35  Show Profile  Reply with Quote
Hi all,

I would like to update a parent table field with a sum obtained from the child table but SQL server gives the error "An aggregate may not appear in the set list of an UPDATE statement". How else can I acheive the same result?

Thanks in advance,

Adi

khtan
In (Som, Ni, Yak)

Singapore
17661 Posts

Posted - 03/01/2006 :  01:06:40  Show Profile  Reply with Quote
post your update statement

----------------------------------
'KH'


Go to Top of Page

shallu1_gupta
Constraint Violating Yak Guru

India
394 Posts

Posted - 03/01/2006 :  01:15:33  Show Profile  Reply with Quote
try this..
update tableparent set column = a.sumcolumn
from
(
select sum(column) as sumcolumn from tablechild
) a
Go to Top of Page

t1g312
Posting Yak Master

United Arab Emirates
148 Posts

Posted - 03/01/2006 :  01:16:23  Show Profile  Reply with Quote
update table1 set table1.Quantity = sum(table2.quantity) from table1 inner join table2 on table1.ID = table2.table1ID
group by table2.ID

quote:
Originally posted by khtan

post your update statement

----------------------------------
'KH'






Adi
Go to Top of Page

khtan
In (Som, Ni, Yak)

Singapore
17661 Posts

Posted - 03/01/2006 :  01:25:00  Show Profile  Reply with Quote
update 	t1
	set	t1.Quantity = t2.sum_qty
from	table1 t1 inner join
	(
		select 	ID, sum(Quantity) as sum_qty
		from	table2
		group by ID
	) as t2
	on	t1.ID	= t2.ID

OR
update 	t1
	set	t1.Quantity	= (select sum(Quantity) from table2 t2 where t2.ID = t1.ID)
from	table1 t1


----------------------------------
'KH'


Go to Top of Page

t1g312
Posting Yak Master

United Arab Emirates
148 Posts

Posted - 03/01/2006 :  01:26:11  Show Profile  Reply with Quote
quote:
Originally posted by shallu1_gupta

try this..
update tableparent set column = a.sumcolumn
from
(
select sum(column) as sumcolumn from tablechild
) a



Brilliant! Thanks man!

Adi
Go to Top of Page

madhivanan
Premature Yak Congratulator

India
22765 Posts

Posted - 03/01/2006 :  03:15:36  Show Profile  Send madhivanan a Yahoo! Message  Reply with Quote
Note that sum of all the rows of child table will be updated to parent table. If you want to update with corresponding primary key values, then use khtan's methods

Madhivanan

Failing to plan is Planning to fail

Edited by - madhivanan on 03/01/2006 03:16:49
Go to Top of Page

t1g312
Posting Yak Master

United Arab Emirates
148 Posts

Posted - 03/01/2006 :  05:42:37  Show Profile  Reply with Quote
quote:
Originally posted by madhivanan

Note that sum of all the rows of child table will be updated to parent table. If you want to update with corresponding primary key values, then use khtan's methods

Madhivanan

Failing to plan is Planning to fail



I already did that. Thanks again guys!

Adi
Go to Top of Page

nakhan82
Starting Member

Netherlands
1 Posts

Posted - 04/19/2010 :  07:29:46  Show Profile  Reply with Quote
ohh wow, thanks, this was so helpfull, I always had to make a new table to 'sum'the columns, but this is much faster!
Go to Top of Page

mikey2nicey
Starting Member

United Kingdom
1 Posts

Posted - 06/25/2010 :  06:41:52  Show Profile  Reply with Quote
This was a great help to me too. Thanks!
Go to Top of Page

wsilage
Yak Posting Veteran

USA
74 Posts

Posted - 09/11/2014 :  15:13:04  Show Profile  Reply with Quote
Thank you so much, this helped! :)


quote:
Originally posted by shallu1_gupta

try this..
update tableparent set column = a.sumcolumn
from
(
select sum(column) as sumcolumn from tablechild
) a

Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.06 seconds. Powered By: Snitz Forums 2000