Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12345»»»

Logic problem in "SET [Quantity_Remaining] = [Quantity_Remaining] - 1" Expand / Collapse
Author
Message
Posted Tuesday, October 16, 2012 10:16 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Thursday, March 13, 2014 2:33 PM
Points: 117, Visits: 315
Any ideas?... I have a trigger (not working obviously) set up that decrements from my [tblBulkPurchases].[Quantity_Remaining] field an amount by one with each entry into my [tblTransactions] when my entry type is 'From Bulk Assignment':

USE [TrackIT]
GO
CREATE TRIGGER [dbo].[trDecrementBulkPurchases]
ON [dbo].[tblTransactions]
AFTER INSERT
AS
BEGIN
UPDATE [TrackIT].[dbo].[tblBulkPurchases]

SET [Quantity_Remaining] = [Quantity_Remaining] - 1

WHERE Transaction_Type = 'From Bulk Assignment'
END
GO
Post #1373389
Posted Tuesday, October 16, 2012 10:20 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 3:13 PM
Points: 12,995, Visits: 12,414
briancampbellmcad (10/16/2012)
Any ideas?... I have a trigger (not working obviously) set up that decrements from my [tblBulkPurchases].[Quantity_Remaining] field an amount by one with each entry into my [tblTransactions] when my entry type is 'From Bulk Assignment':

USE [TrackIT]
GO
CREATE TRIGGER [dbo].[trDecrementBulkPurchases]
ON [dbo].[tblTransactions]
AFTER INSERT
AS
BEGIN
UPDATE [TrackIT].[dbo].[tblBulkPurchases]

SET [Quantity_Remaining] = [Quantity_Remaining] - 1

WHERE Transaction_Type = 'From Bulk Assignment'
END
GO


You have not joined to the pseudo table INSERTED. The way you have this coded is it will update every row in the table that meets the where condition.

with no ddl to work with you probably want something like this.

UPDATE [TrackIT].[dbo].[tblBulkPurchases]

SET [Quantity_Remaining] = [Quantity_Remaining] - 1

WHERE Transaction_Type = 'From Bulk Assignment'
and YourKeyField in (select YourKeyField from Inserted)



_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1373392
Posted Tuesday, October 16, 2012 11:29 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Thursday, March 13, 2014 2:33 PM
Points: 117, Visits: 315
Gave this a try to no avail:

USE [TrackIT]
GO
CREATE TRIGGER [dbo].[trDecrementBulkPurchases]
ON [dbo].[tblTransactions]
AFTER INSERT
AS
BEGIN
UPDATE [TrackIT].[dbo].[tblBulkPurchases]
SET [Quantity_Remaining] = [Quantity_Remaining] - 1
WHERE Transaction_Type = 'From Bulk Assignment' AND
[tblBulkPurchases].[PO_Number] IN (SELECT [PO_Number] FROM [tblTransactions])
END
GO

Here are my DDL of Tables:

USE [TrackIT]
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[tblTransactions](
[PO_Number] [varchar](50) NULL,
[Buyer_Initial] [varchar](50) NULL,
[Software_ID] [varchar](50) NULL,
[Quantity] [int] NULL,
[Unit_Price] [money] NULL,
[Software_Description] [varchar](100) NULL,
[AllocationAccount] [varchar](50) NULL,
[PurchaseAccount] [varchar](50) NULL,
[HeatTicketNumber] [varchar](50) NULL,
[PurchaseCostCenter] [varchar](25) NULL,
[PO_Date] [date] NULL,
[Transaction_Date] [date] NULL,
[Transaction_Number] [int] NOT NULL,
[AllocationDate] [date] NULL,
[AllocatedYN] [varchar](10) NULL,
[Emp_ID] [varchar](50) NULL,
[EndUserFirstName] [varchar](100) NULL,
[EndUserMiddleName] [varchar](100) NULL,
[EndUserLastName] [varchar](100) NULL,
[Cost_Center] [varchar](50) NULL,
[LAN_ID] [varchar](50) NULL,
[EndUserLocation] [varchar](100) NULL,
[TermDate] [date] NULL,
[EmployeeStatus] [varchar](50) NULL,
[UserCostCenter] [varchar](25) NULL,
[TransferFrom] [varchar](100) NULL,
[TransferTo] [varchar](100) NULL,
[Equipment_Type] [varchar](50) NULL,
[Notes] [varchar](255) NULL,
[License_Available] [varchar](50) NULL,
[Transaction_Type] [varchar](50) NULL,
[NextRenewalDate] [date] NULL,
[Last_Renewal_Date] [date] NULL,
[LastRenewalPO] [varchar](50) NULL,
[Quantity_Remaining] [int] NULL,
CONSTRAINT [PK_dbo.tblTransactions] PRIMARY KEY CLUSTERED
(
[Transaction_Number] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO



USE [TrackIT]
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[tblBulkPurchases](
[PO_Number] [varchar](50) NOT NULL,
[Buyer_Initial] [varchar](50) NULL,
[Software_ID] [varchar](50) NULL,
[Quantity] [int] NULL,
[Quantity_Remaining] [int] NULL,
[Unit_Price] [money] NULL,
[Software_Description] [varchar](100) NULL,
[AllocationAccount] [varchar](50) NULL,
[PurchaseAccount] [varchar](50) NULL,
[HeatTicketNumber] [varchar](50) NULL,
[PurchaseCostCenter] [varchar](25) NULL,
[PO_Date] [date] NULL,
[Transaction_Date] [date] NULL,
[Transaction_Number] [int] NOT NULL,
[Transaction_Type] [varchar](50) NULL,
CONSTRAINT [PK_dbo.tblBulkPurchases] PRIMARY KEY CLUSTERED
(
[PO_Number] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
Post #1373428
Posted Tuesday, October 16, 2012 11:34 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 3:13 PM
Points: 12,995, Visits: 12,414
Did you read my post? You need to refer to the INSERTED table which in your code you still don't. The way you have it coded is that it will update the entire table that meets the where condition.

Thanks for the ddl but without some sample data and desired output it is hard to test. And with no explanation of what you want we don't know what "it doesn't work" means.


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1373431
Posted Tuesday, October 16, 2012 11:42 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Thursday, March 13, 2014 2:33 PM
Points: 117, Visits: 315
I read the post but I'm sure I misunderstood something -

Here's a typical insert to the tblTransactions:

INSERT INTO [TrackIT].[dbo].[tblTransactions]
([Buyer_Initial]
,[PO_Number]
,[Software_ID]
,[Transaction_Number]
,[Transaction_Type])
VALUES
('OCC',
'5465115',
'51',
17901,
'From Bulk Assignment')
GO
Post #1373434
Posted Tuesday, October 16, 2012 12:39 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 5:09 PM
Points: 39,968, Visits: 36,327
Inside a trigger you have access to the inserted and deleted pseudo-tables which contain the rows that were affected by the operation that fired the trigger. You need to change the trigger so that the update joins or filters based on the inserted table so that it only updates rows that were affected by the insert.




Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1373467
Posted Tuesday, October 16, 2012 1:38 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Thursday, March 13, 2014 2:33 PM
Points: 117, Visits: 315
Let me make sure I understand this line by line and have each right so far...

First, isn't the line "WHERE Transaction_Type = 'From Bulk Assignment'"
correctly referenceing the INSERTED with no additional qualifiers for this line needed?

USE [TrackIT]
GO
CREATE TRIGGER [dbo].[trDecrementBulkPurchases]
ON [dbo].[tblTransactions]
AFTER INSERT
AS
BEGIN
UPDATE [TrackIT].[dbo].[tblBulkPurchases]
SET [Quantity_Remaining] = [Quantity_Remaining] - 1
WHERE Transaction_Type = 'From Bulk Assignment'
AND PO_Number IN (SELECT [PO_Number] FROM [tblBulkPurchases])
END
GO

WHERE Transaction_Type = 'From Bulk Assignment'
Post #1373500
Posted Tuesday, October 16, 2012 1:53 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 5:09 PM
Points: 39,968, Visits: 36,327
briancampbellmcad (10/16/2012)
Let me make sure I understand this line by line and have each right so far...

First, isn't the line "WHERE Transaction_Type = 'From Bulk Assignment'"
correctly referenceing the INSERTED with no additional qualifiers for this line needed?


No, that'll match all then rows in the table that have a transaction type of 'From Bulk Assignment', regardless of when they were inserted or when they got that value.



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1373512
Posted Wednesday, October 17, 2012 7:03 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Thursday, March 13, 2014 2:33 PM
Points: 117, Visits: 315
That last part makes sense...
I'm thinking an "IF" condition on transaction_type may be a step in the right direction (?):

USE [TrackIT]
GO
CREATE TRIGGER [dbo].[trDecrementBulkPurchases]
ON [dbo].[tblTransactions]
AFTER INSERT
AS
BEGIN

IF Transaction_Type = 'From Bulk Assignment'

UPDATE [TrackIT].[dbo].[tblBulkPurchases]
SET [Quantity_Remaining] = [Quantity_Remaining] - 1
WHERE PO_Number IN (SELECT [PO_Number] FROM [tblTransactions])

END IF

END
GO

-- there are some syntax issues of course
Post #1373771
Posted Wednesday, October 17, 2012 7:08 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 3:13 PM
Points: 12,995, Visits: 12,414
briancampbellmcad (10/17/2012)
That last part makes sense...
I'm thinking an "IF" condition on transaction_type may be a step in the right direction (?):

USE [TrackIT]
GO
CREATE TRIGGER [dbo].[trDecrementBulkPurchases]
ON [dbo].[tblTransactions]
AFTER INSERT
AS
BEGIN

IF Transaction_Type = 'From Bulk Assignment'

UPDATE [TrackIT].[dbo].[tblBulkPurchases]
SET [Quantity_Remaining] = [Quantity_Remaining] - 1
WHERE PO_Number IN (SELECT [PO_Number] FROM [tblTransactions])

END IF

END
GO

-- there are some syntax issues of course


No that is not the right direction. You need to go read the trigger documentation. Both Gail and I have suggested repeatedly that you need to use the INSERTED table. My very first response is probably very close to what you want. We still don't have ddl, sample data or an explanation of what you want. Without that the best we can do is guess.


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1373775
« Prev Topic | Next Topic »

Add to briefcase 12345»»»

Permissions Expand / Collapse