wikibot[edit]
Table
|
Sales.SalesOrderDetail
|
Description
|
Individual products associated with a specific sales order. See SalesOrderHeader.
|
Columns[edit]
Column
|
Data Type
|
Nullable
|
Default
|
Description
|
SalesOrderID
|
int
|
not null
|
|
Primary key. Foreign key to SalesOrderHeader.SalesOrderID.
|
SalesOrderDetailID
|
int
|
not null
|
|
Primary key. One incremental unique number per product sold.
|
CarrierTrackingNumber
|
nvarchar(25)
|
null
|
|
Shipment tracking number supplied by the shipper.
|
OrderQty
|
smallint
|
not null
|
|
Quantity ordered per product.
|
ProductID
|
int
|
not null
|
|
Product sold to customer. Foreign key to Product.ProductID.
|
SpecialOfferID
|
int
|
not null
|
|
Promotional code. Foreign key to SpecialOffer.SpecialOfferID.
|
UnitPrice
|
money
|
not null
|
|
Selling price of a single product.
|
UnitPriceDiscount
|
money
|
not null
|
((0.0))
|
Discount amount.
|
LineTotal
|
|
|
|
Per product subtotal. Computed as UnitPrice * (1 - UnitPriceDiscount) * OrderQty.
|
rowguid
|
uniqueidentifier
|
not null
|
(newid())
|
ROWGUIDCOL number uniquely identifying the record. Used to support a merge replication sample.
|
ModifiedDate
|
datetime
|
not null
|
(getdate())
|
Date and time the record was last updated.
|
Primary Key[edit]
Primary Key
|
Columns
|
PK_SalesOrderDetail_SalesOrderID_SalesOrderDetailID
|
SalesOrderID, SalesOrderDetailID
|
Indexes[edit]
Index
|
Type
|
Columns
|
AK_SalesOrderDetail_rowguid
|
Unique
|
rowguid
|
IX_SalesOrderDetail_ProductID
|
|
ProductID
|
Check Constraints[edit]
Check Constraint
|
Expression
|
Description
|
CK_SalesOrderDetail_OrderQty
|
([OrderQty]>(0))
|
Check constraint [OrderQty] > (0)
|
CK_SalesOrderDetail_UnitPrice
|
([UnitPrice]>=(0.00))
|
Check constraint [UnitPrice] >= (0.00)
|
CK_SalesOrderDetail_UnitPriceDiscount
|
([UnitPriceDiscount]>=(0.00))
|
Check constraint [UnitPriceDiscount] >= (0.00)
|
Foreign Keys[edit]
Triggers[edit]
Trigger
|
Type
|
iduSalesOrderDetail
|
ON INSERT UPDATE DELETE
|
Trigger iduSalesOrderDetail[edit]
CREATE TRIGGER [Sales].[iduSalesOrderDetail] ON [Sales].[SalesOrderDetail]
AFTER INSERT, DELETE, UPDATE AS
BEGIN
DECLARE @Count int;
SET @Count = @@ROWCOUNT;
IF @Count = 0
RETURN;
SET NOCOUNT ON;
BEGIN TRY
-- If inserting or updating these columns
IF UPDATE([ProductID]) OR UPDATE([OrderQty]) OR UPDATE([UnitPrice]) OR UPDATE([UnitPriceDiscount])
-- Insert record into TransactionHistory
BEGIN
INSERT INTO [Production].[TransactionHistory]
([ProductID]
,[ReferenceOrderID]
,[ReferenceOrderLineID]
,[TransactionType]
,[TransactionDate]
,[Quantity]
,[ActualCost])
SELECT
inserted.[ProductID]
,inserted.[SalesOrderID]
,inserted.[SalesOrderDetailID]
,'S'
,GETDATE()
,inserted.[OrderQty]
,inserted.[UnitPrice]
FROM inserted
INNER JOIN [Sales].[SalesOrderHeader]
ON inserted.[SalesOrderID] = [Sales].[SalesOrderHeader].[SalesOrderID];
UPDATE [Sales].[Individual]
SET [Demographics].modify('declare default element namespace
"http://schemas.microsoft.com/sqlserver/2004/07/adventure-works/IndividualSurvey";
replace value of (/IndividualSurvey/TotalPurchaseYTD)[1]
with data(/IndividualSurvey/TotalPurchaseYTD)[1] + sql:column ("inserted.LineTotal")')
FROM inserted
INNER JOIN [Sales].[SalesOrderHeader]
ON inserted.[SalesOrderID] = [Sales].[SalesOrderHeader].[SalesOrderID]
WHERE [Sales].[SalesOrderHeader].[CustomerID] = [Sales].[Individual].[CustomerID];
END;
-- Update SubTotal in SalesOrderHeader record. Note that this causes the
-- SalesOrderHeader trigger to fire which will update the RevisionNumber.
UPDATE [Sales].[SalesOrderHeader]
SET [Sales].[SalesOrderHeader].[SubTotal] =
(SELECT SUM([Sales].[SalesOrderDetail].[LineTotal])
FROM [Sales].[SalesOrderDetail]
WHERE [Sales].[SalesOrderHeader].[SalesOrderID] = [Sales].[SalesOrderDetail].[SalesOrderID])
WHERE [Sales].[SalesOrderHeader].[SalesOrderID] IN (SELECT inserted.[SalesOrderID] FROM inserted);
UPDATE [Sales].[Individual]
SET [Demographics].modify('declare default element namespace
"http://schemas.microsoft.com/sqlserver/2004/07/adventure-works/IndividualSurvey";
replace value of (/IndividualSurvey/TotalPurchaseYTD)[1]
with data(/IndividualSurvey/TotalPurchaseYTD)[1] - sql:column("deleted.LineTotal")')
FROM deleted
INNER JOIN [Sales].[SalesOrderHeader]
ON deleted.[SalesOrderID] = [Sales].[SalesOrderHeader].[SalesOrderID]
WHERE [Sales].[SalesOrderHeader].[CustomerID] = [Sales].[Individual].[CustomerID];
END TRY
BEGIN CATCH
EXECUTE [dbo].[uspPrintError];
-- Rollback any active or uncommittable transactions before
-- inserting information in the ErrorLog
IF @@TRANCOUNT > 0
BEGIN
ROLLBACK TRANSACTION;
END
EXECUTE [dbo].[uspLogError];
END CATCH;
END;
References[edit]
Dependencies[edit]
Reference Type
|
Object Type
|
Referencing Object
|
Child Type
|
Child Object
|
Select
|
Table
|
Sales.SalesOrderDetail
|
Trigger
|
iduSalesOrderDetail
|
automatically generated[edit]
Table
|
Sales.SalesOrderDetail
|
Description
|
Individual products associated with a specific sales order. See SalesOrderHeader.
|
Column
|
Data Type
|
Nullable
|
Default
|
Description / PK / Index
|
SalesOrderID
|
int
|
not null
|
|
Primary key. Foreign key to SalesOrderHeader.SalesOrderID. PK_SalesOrderDetail_SalesOrderID_SalesOrderDetailID
|
SalesOrderDetailID
|
int
|
not null
|
|
Primary key. One incremental unique number per product sold. PK_SalesOrderDetail_SalesOrderID_SalesOrderDetailID
|
CarrierTrackingNumber
|
nvarchar(25)
|
null
|
|
Shipment tracking number supplied by the shipper.
|
OrderQty
|
smallint
|
not null
|
|
Quantity ordered per product.
|
ProductID
|
int
|
not null
|
|
Product sold to customer. Foreign key to Product.ProductID. IX_SalesOrderDetail_ProductID
|
SpecialOfferID
|
int
|
not null
|
|
Promotional code. Foreign key to SpecialOffer.SpecialOfferID.
|
UnitPrice
|
money
|
not null
|
|
Selling price of a single product.
|
UnitPriceDiscount
|
money
|
not null
|
(0.0)
|
Discount amount.
|
LineTotal
|
|
|
|
Per product subtotal. Computed as UnitPrice * (1 - UnitPriceDiscount) * OrderQty.
|
rowguid
|
uniqueidentifier
|
not null
|
(NEWID())
|
ROWGUIDCOL number uniquely identifying the record. Used to support a merge replication sample. AK_SalesOrderDetail_rowguid
|
ModifiedDate
|
datetime
|
not null
|
(GETDATE())
|
Date and time the record was last updated.
|
Triggers
|
Type
|
iduSalesOrderDetail
|
ON INSERT UPDATE DELETE
|
Reference Type
|
Object Type
|
Referencing Object
|
Child Type
|
Child Object
|
Select
|
Table
|
Sales.SalesOrderDetail
|
Trigger
|
iduSalesOrderDetail
|