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 2005 Forums
 Other SQL Server Topics (2005)
 sum function
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

taniarto
Starting Member

Indonesia
27 Posts

Posted - 09/27/2013 :  21:58:22  Show Profile  Reply with Quote
Dear All,

I have 2 tables :
1. Table sales

ID item qty
001 ICe 20
002 Book 10
003 Book 20

2. Table Stock

ID qty
001 20
002 30

I create a trigger on Sales Table :

set ANSI_NULLS ON
set QUOTED_IDENTIFIER ON
go

ALTER TRIGGER [insert_sales] ON [dbo].[sales]
for INSERT,update
AS
declare @id_ varchar(20)
declare @qty int

IF EXISTS(
SELECT id
FROM sales where id=@id )
begin
update s
set s.qty=i.qty from stock s
join
(select id,sum(qty) as qty from inserted group by id) i
on s.id=i.id
end


the trigger is running but the result only show the latest record not all of the sum calculation.

The result show :

ID Qty
002 20

not 30 ( as all record result)

Please help..
thanks



visakh16
Very Important crosS Applying yaK Herder

India
52317 Posts

Posted - 09/28/2013 :  05:53:12  Show Profile  Reply with Quote
why do need IF EXISTS? isnt below enough?

ALTER TRIGGER [insert_sales] ON [dbo].[sales] 
for INSERT,update 
AS


update s 
set s.qty=i.qty from stock s
join 
(select id,sum(qty) as qty from inserted group by id) i
on s.id=i.id 





------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

taniarto
Starting Member

Indonesia
27 Posts

Posted - 09/30/2013 :  04:02:05  Show Profile  Reply with Quote
If the record were deleted, is it calculated into the new calculation?
or we must make a delete trigger too?

thanks

quote:
Originally posted by visakh16

why do need IF EXISTS? isnt below enough?

ALTER TRIGGER [insert_sales] ON [dbo].[sales] 
for INSERT,update 
AS


update s 
set s.qty=i.qty from stock s
join 
(select id,sum(qty) as qty from inserted group by id) i
on s.id=i.id 





------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs


Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

India
52317 Posts

Posted - 09/30/2013 :  06:20:22  Show Profile  Reply with Quote
quote:
Originally posted by taniarto

If the record were deleted, is it calculated into the new calculation?
or we must make a delete trigger too?

thanks

quote:
Originally posted by visakh16

why do need IF EXISTS? isnt below enough?

ALTER TRIGGER [insert_sales] ON [dbo].[sales] 
for INSERT,update 
AS


update s 
set s.qty=i.qty from stock s
join 
(select id,sum(qty) as qty from inserted group by id) i
on s.id=i.id 





------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs





current logic doesnt account deletes

if you want to include it too make trigger like


ALTER TRIGGER [insert_sales] ON [dbo].[sales] 
for INSERT,update ,Delete
AS


update s 
set s.qty=s.qty + i.qty - d.qty  from stock s
left join 
(select id,sum(qty) as qty from inserted group by id) i
on s.id=i.id 
left join 
(select id,sum(qty) as qty from deleted group by id) d
on s.id=d.id 



------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

SwePeso
Patron Saint of Lost Yaks

Sweden
30265 Posts

Posted - 09/30/2013 :  08:36:12  Show Profile  Visit SwePeso's Homepage  Reply with Quote
You need a MERGE, because what happens when you delete the last row from Sales?
ALTER TRIGGER	dbo.trgSales
ON		dbo.Sales 
AFTER		INSERT,
		UPDATE,
		DELETE
AS

SET NOCOUNT ON;

MERGE	dbo.Stock AS tgt
USING	(
		SELECT		ID,
				SUM(Qty) AS Qty
		FROM		dbo.Sales
		GROUP BY	ID
	) AS src ON src.ID = tgt.ID
WHEN	MATCHED AND tgt.Qty <> src.Qty
		THEN	UPDATE
			SET	tgt.Qty = src.Qty
WHEN	NOT MATCHED BY TARGET
		THEN	INSERT	(
					ID,
					Qty
				)
			VALUES	(
					src.ID,
					src.Qty
				)
WHEN	NOT MATCHED BY SOURCE
		THEN	DELETE;



Microsoft SQL Server MVP, MCT, MCSE, MCSA, MCP, MCITP, MCTS, MCDBA
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.07 seconds. Powered By: Snitz Forums 2000