Tables [Sales].[SalesOrderDetail]
Individual products associated with a specific sales order. See SalesOrderHeader.
PropertyValue
CollationSQL_Latin1_General_CP1_CI_AS
Row Count (~)121317
Created13:14:19 14 marca 2012
Last Modified13:14:55 14 marca 2012
KeyNameData TypeComputedMax Length (Bytes)Allow NullsIdentityDefaultDescription
Cluster Primary Key PK_SalesOrderDetail_SalesOrderID_SalesOrderDetailID: SalesOrderID\SalesOrderDetailIDForeign Keys FK_SalesOrderDetail_SalesOrderHeader_SalesOrderID: [Sales].[SalesOrderHeader].SalesOrderIDSalesOrderIDint4
False
Primary key. Foreign key to SalesOrderHeader.SalesOrderID.
Cluster Primary Key PK_SalesOrderDetail_SalesOrderID_SalesOrderDetailID: SalesOrderID\SalesOrderDetailIDSalesOrderDetailIDint4
False
1 - 1Primary key. One incremental unique number per product sold.
CarrierTrackingNumbernvarchar(25)50
True
Shipment tracking number supplied by the shipper.
Check Constraints CK_SalesOrderDetail_OrderQty : ([OrderQty]>(0))OrderQtysmallint2
False
Quantity ordered per product.
Indexes IX_SalesOrderDetail_ProductIDForeign Keys FK_SalesOrderDetail_SpecialOfferProduct_SpecialOfferIDProductID: [Sales].[SpecialOfferProduct].SpecialOfferID\ProductIDProductIDint4
False
Product sold to customer. Foreign key to Product.ProductID.
Foreign Keys FK_SalesOrderDetail_SpecialOfferProduct_SpecialOfferIDProductID: [Sales].[SpecialOfferProduct].SpecialOfferID\ProductIDSpecialOfferIDint4
False
Promotional code. Foreign key to SpecialOffer.SpecialOfferID.
Check Constraints CK_SalesOrderDetail_UnitPrice : ([UnitPrice]>=(0.00))UnitPricemoney8
False
Selling price of a single product.
Check Constraints CK_SalesOrderDetail_UnitPriceDiscount : ([UnitPriceDiscount]>=(0.00))UnitPriceDiscountmoney8
False
((0.0))Discount amount.
LineTotalnumeric(38,6)
True
17
False
Per product subtotal. Computed as UnitPrice * (1 - UnitPriceDiscount) * OrderQty.
Indexes AK_SalesOrderDetail_rowguidrowguiduniqueidentifier16
False
(newid())ROWGUIDCOL number uniquely identifying the record. Used to support a merge replication sample.
ModifiedDatedatetime8
False
(getdate())Date and time the record was last updated.
NameColumn definition
LineTotal(isnull(([UnitPrice]*((1.0)-[UnitPriceDiscount]))*[OrderQty],(0.0)))
KeyNameKey ColumnsUniqueDescription
Cluster Primary Key PK_SalesOrderDetail_SalesOrderID_SalesOrderDetailID: SalesOrderID\SalesOrderDetailIDPK_SalesOrderDetail_SalesOrderID_SalesOrderDetailIDSalesOrderID, SalesOrderDetailID
True
Primary key (clustered) constraint
AK_SalesOrderDetail_rowguidrowguid
True
Unique nonclustered index. Used to support replication samples.
IX_SalesOrderDetail_ProductIDProductIDNonclustered index.
NameANSI Nulls OnQuoted Identifier OnOnDescription
iduSalesOrderDetail
True
True
After Delete Insert UpdateAFTER INSERT, DELETE, UPDATE trigger that inserts a row in the TransactionHistory table, updates ModifiedDate in SalesOrderDetail and updates the SalesOrderHeader.SubTotal column.
NameOn ColumnConstraintDescription
CK_SalesOrderDetail_OrderQtyOrderQty([OrderQty]>(0))Check constraint [OrderQty] > (0)
CK_SalesOrderDetail_UnitPriceUnitPrice([UnitPrice]>=(0.00))Check constraint [UnitPrice] >= (0.00)
CK_SalesOrderDetail_UnitPriceDiscountUnitPriceDiscount([UnitPriceDiscount]>=(0.00))Check constraint [UnitPriceDiscount] >= (0.00)
NameDeleteColumnsDescription
FK_SalesOrderDetail_SalesOrderHeader_SalesOrderIDCascadeSalesOrderID->[Sales].[SalesOrderHeader].[SalesOrderID]Foreign key constraint referencing SalesOrderHeader.PurchaseOrderID.
FK_SalesOrderDetail_SpecialOfferProduct_SpecialOfferIDProductIDSpecialOfferID->[Sales].[SpecialOfferProduct].[SpecialOfferID]
ProductID->[Sales].[SpecialOfferProduct].[ProductID]
Foreign key constraint referencing SpecialOfferProduct.SpecialOfferIDProductID.
CREATE TABLE [Sales].[SalesOrderDetail]
(
[SalesOrderID] [int] NOT NULL,
[SalesOrderDetailID] [int] NOT NULL IDENTITY(1, 1),
[CarrierTrackingNumber] [nvarchar] (25) COLLATE SQL_Latin1_General_CP1_CI_AS NULL,
[OrderQty] [smallint] NOT NULL,
[ProductID] [int] NOT NULL,
[SpecialOfferID] [int] NOT NULL,
[UnitPrice] [money] NOT NULL,
[UnitPriceDiscount] [money] NOT NULL CONSTRAINT [DF_SalesOrderDetail_UnitPriceDiscount] DEFAULT ((0.0)),
[LineTotal] AS (isnull(([UnitPrice]*((1.0)-[UnitPriceDiscount]))*[OrderQty],(0.0))),
[rowguid] [uniqueidentifier] NOT NULL ROWGUIDCOL CONSTRAINT [DF_SalesOrderDetail_rowguid] DEFAULT (newid()),
[ModifiedDate] [datetime] NOT NULL CONSTRAINT [DF_SalesOrderDetail_ModifiedDate] DEFAULT (getdate())
) ON [PRIMARY]
GO

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 [Person].[Person]
           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] AS SOH
               ON inserted.[SalesOrderID] = SOH.[SalesOrderID]
               INNER JOIN [Sales].[Customer] AS C
               ON SOH.[CustomerID] = C.[CustomerID]
           WHERE C.[PersonID] = [Person].[Person].[BusinessEntityID];
       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 [Person].[Person]
       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]
           INNER JOIN [Sales].[Customer]
           ON [Sales].[Customer].[CustomerID] = [Sales].[SalesOrderHeader].[CustomerID]
       WHERE [Sales].[Customer].[PersonID] = [Person].[Person].[BusinessEntityID];
   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;
GO
ALTER TABLE [Sales].[SalesOrderDetail] ADD CONSTRAINT [CK_SalesOrderDetail_OrderQty] CHECK (([OrderQty]>(0)))
GO
ALTER TABLE [Sales].[SalesOrderDetail] ADD CONSTRAINT [CK_SalesOrderDetail_UnitPrice] CHECK (([UnitPrice]>=(0.00)))
GO
ALTER TABLE [Sales].[SalesOrderDetail] ADD CONSTRAINT [CK_SalesOrderDetail_UnitPriceDiscount] CHECK (([UnitPriceDiscount]>=(0.00)))
GO
ALTER TABLE [Sales].[SalesOrderDetail] ADD CONSTRAINT [PK_SalesOrderDetail_SalesOrderID_SalesOrderDetailID] PRIMARY KEY CLUSTERED  ([SalesOrderID], [SalesOrderDetailID]) ON [PRIMARY]
GO
CREATE NONCLUSTERED INDEX [IX_SalesOrderDetail_ProductID] ON [Sales].[SalesOrderDetail] ([ProductID]) ON [PRIMARY]
GO
CREATE UNIQUE NONCLUSTERED INDEX [AK_SalesOrderDetail_rowguid] ON [Sales].[SalesOrderDetail] ([rowguid]) ON [PRIMARY]
GO
ALTER TABLE [Sales].[SalesOrderDetail] ADD CONSTRAINT [FK_SalesOrderDetail_SalesOrderHeader_SalesOrderID] FOREIGN KEY ([SalesOrderID]) REFERENCES [Sales].[SalesOrderHeader] ([SalesOrderID]) ON DELETE CASCADE
GO
ALTER TABLE [Sales].[SalesOrderDetail] ADD CONSTRAINT [FK_SalesOrderDetail_SpecialOfferProduct_SpecialOfferIDProductID] FOREIGN KEY ([SpecialOfferID], [ProductID]) REFERENCES [Sales].[SpecialOfferProduct] ([SpecialOfferID], [ProductID])
GO
EXEC sp_addextendedproperty N'MS_Description', N'Individual products associated with a specific sales order. See SalesOrderHeader.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', NULL, NULL
GO
EXEC sp_addextendedproperty N'MS_Description', N'Shipment tracking number supplied by the shipper.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'COLUMN', N'CarrierTrackingNumber'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Per product subtotal. Computed as UnitPrice * (1 - UnitPriceDiscount) * OrderQty.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'COLUMN', N'LineTotal'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Date and time the record was last updated.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'COLUMN', N'ModifiedDate'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Quantity ordered per product.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'COLUMN', N'OrderQty'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Product sold to customer. Foreign key to Product.ProductID.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'COLUMN', N'ProductID'
GO
EXEC sp_addextendedproperty N'MS_Description', N'ROWGUIDCOL number uniquely identifying the record. Used to support a merge replication sample.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'COLUMN', N'rowguid'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Primary key. One incremental unique number per product sold.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'COLUMN', N'SalesOrderDetailID'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Primary key. Foreign key to SalesOrderHeader.SalesOrderID.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'COLUMN', N'SalesOrderID'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Promotional code. Foreign key to SpecialOffer.SpecialOfferID.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'COLUMN', N'SpecialOfferID'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Selling price of a single product.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'COLUMN', N'UnitPrice'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Discount amount.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'COLUMN', N'UnitPriceDiscount'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Check constraint [OrderQty] > (0)', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'CONSTRAINT', N'CK_SalesOrderDetail_OrderQty'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Check constraint [UnitPrice] >= (0.00)', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'CONSTRAINT', N'CK_SalesOrderDetail_UnitPrice'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Check constraint [UnitPriceDiscount] >= (0.00)', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'CONSTRAINT', N'CK_SalesOrderDetail_UnitPriceDiscount'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Default constraint value of GETDATE()', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'CONSTRAINT', N'DF_SalesOrderDetail_ModifiedDate'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Default constraint value of NEWID()', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'CONSTRAINT', N'DF_SalesOrderDetail_rowguid'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Default constraint value of 0.0', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'CONSTRAINT', N'DF_SalesOrderDetail_UnitPriceDiscount'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Foreign key constraint referencing SalesOrderHeader.PurchaseOrderID.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'CONSTRAINT', N'FK_SalesOrderDetail_SalesOrderHeader_SalesOrderID'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Foreign key constraint referencing SpecialOfferProduct.SpecialOfferIDProductID.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'CONSTRAINT', N'FK_SalesOrderDetail_SpecialOfferProduct_SpecialOfferIDProductID'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Primary key (clustered) constraint', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'CONSTRAINT', N'PK_SalesOrderDetail_SalesOrderID_SalesOrderDetailID'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Unique nonclustered index. Used to support replication samples.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'INDEX', N'AK_SalesOrderDetail_rowguid'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Nonclustered index.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'INDEX', N'IX_SalesOrderDetail_ProductID'
GO
EXEC sp_addextendedproperty N'MS_Description', N'Clustered index created by a primary key constraint.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'INDEX', N'PK_SalesOrderDetail_SalesOrderID_SalesOrderDetailID'
GO
EXEC sp_addextendedproperty N'MS_Description', N'AFTER INSERT, DELETE, UPDATE trigger that inserts a row in the TransactionHistory table, updates ModifiedDate in SalesOrderDetail and updates the SalesOrderHeader.SubTotal column.', 'SCHEMA', N'Sales', 'TABLE', N'SalesOrderDetail', 'TRIGGER', N'iduSalesOrderDetail'
GO