Description: This is a sample basic Type II dimension table. This is to be used for non-junk dimension dimensions. There is a separate example for junk dimensions.
Necessary Modification:
Replace YourEDW with the name for your specific data warehouse.
Replace YourDimensionName with the name of your dimension.
Then fill in your columns on line 14.
USE [YourEDW]DROPTABLEIF EXISTS [dw].[DimYourDimensionName]GOSET ANSI_NULLS ONGOSET QUOTED_IDENTIFIER ONGOCREATE TABLE [dw].[DimYourDimensionName]([YourDimensionNameCK] [bigint] IDENTITY(1,1) NOT NULL,--your columns here.[RowHash] AS (CONVERT([binary](16),hashbytes('MD5',concat(CONVERT([nvarchar](35),Column1,0),CONVERT([nvarchar](35),Column2,0),CONVERT([nvarchar](35),Column3,0),CONVERT([nvarchar](35),Column4,0),CONVERT([nvarchar](35),Column5,0),CONVERT([nvarchar](35),Column6,0))),0)) PERSISTED,[CreatedBy] [nvarchar](50) NULL,[CreatedOn] [datetime] NULL,[UpdatedBy] [nvarchar](50) NULL,[UpdatedOn] [datetime] NULL,[SourceSystem] [nvarchar](100) NULL,[SourceSystemKey] [nvarchar](100) NULL,[EffectiveFrom] [datetime] NULL,[EffectiveTo] [datetime] NULL,[IsMostRecentRecord] [bit] NULL CONSTRAINT [PK_YourDimensionName] PRIMARY KEY CLUSTERED ( [YourDimensionNameCK] 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--index is optionalDROP INDEX IF EXISTS [NCIDX_DimYourDimensionName_SourceSystemKey] ON [dw].[DimYourDimensionName]GOCREATE NONCLUSTERED INDEX [NCIDX_DimYourDimensionName_SourceSystemKey] ON [dw].[DimYourDimensionName]( [SourceSystemKey] ASC)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS =ON, ALLOW_PAGE_LOCKS =ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]GO