Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 SQL Server 2000 Forums
 Transact-SQL (2000)
 Update field with aggregate value?

Author  Topic 

t1g312
Posting Yak Master

148 Posts

Posted - 2006-03-01 : 01:02:35
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)

17689 Posts

Posted - 2006-03-01 : 01:06:40
post your update statement

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


Go to Top of Page

shallu1_gupta
Constraint Violating Yak Guru

394 Posts

Posted - 2006-03-01 : 01:15:33
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

148 Posts

Posted - 2006-03-01 : 01:16:23
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)

17689 Posts

Posted - 2006-03-01 : 01:25:00
[code]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[/code]
OR
[code]update t1
set t1.Quantity = (select sum(Quantity) from table2 t2 where t2.ID = t1.ID)
from table1 t1[/code]

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


Go to Top of Page

t1g312
Posting Yak Master

148 Posts

Posted - 2006-03-01 : 01:26:11
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

22864 Posts

Posted - 2006-03-01 : 03:15:36
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
Go to Top of Page

t1g312
Posting Yak Master

148 Posts

Posted - 2006-03-01 : 05:42:37
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

1 Post

Posted - 2010-04-19 : 07:29:46
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

1 Post

Posted - 2010-06-25 : 06:41:52
This was a great help to me too. Thanks!
Go to Top of Page

wsilage
Yak Posting Veteran

82 Posts

Posted - 2014-09-11 : 15:13:04
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
   

- Advertisement -