Home > Articles > Data

Like this article? We recommend

Like this article? We recommend

Dimensional Modeling

Dimensional modeling is somewhat different from its relational counterpart. I won’t go into details of dimensional modeling here because such concepts have fine coverage in several books that each DW architect should read. Most commonly referenced dimensional modeling authors are Bill Inmon and Ralph Kimball.

For the purposes of this article, I’ll suffice to say that dimensional models consist of the fact and dimension tables. Typical fact tables contain numerous foreign keys referencing dimension tables. Dimension tables, on the other hand, usually contain very few columns—dimension key, value, create, and update date, and perhaps an obsolete date. Fact tables record occurrences of a measurable fact, such as customer orders. Dimension tables provide a way to slice business data across various diagonals of company’s operations; for example, we can examine orders by customer or by product.

You can use the "obsolete_date" column within dimension tables to track the history of values that change over time. This concept is known as slowly changing dimension. For example, consumers of your products might change their last names due to marriage, divorce, or for another personal reason. Similarly multiple departments within your organization can be combined into one, or one department can be divided. In some cases, you care to keep just the current value. If so, consider yourself lucky—you can simply override the existing value with the new value in the dimension table. In other cases, you must keep track of the old value as well as the new value. This is when you use the record obsolete date to track the timeframe during which the record was valid.

Northwind trader’s dimensional model will be very simple, consisting of four-dimension tables and a fact table. Notice that because this is just a static database and I won’t have any new data to populate it regularly, I won’t add the obsolete_date column to the dimensions. You can create fact and dimension tables using the following script:

CREATE TABLE dbo.dim_supplier(
  supplier_ident INT IDENTITY(1, 1), 
  supplier_id INT NOT NULL, 
  supplier_name VARCHAR(255) NOT NULL, 
  supplier_city VARCHAR (255) NULL, 
  country VARCHAR(255) NULL
)

CREATE TABLE dbo.dim_product (
  product_ident INT IDENTITY(1, 1), 
  product_id INT NOT NULL, 
  product_name VARCHAR(255) NOT NULL, 
  discontinued BIT NOT NULL
)


CREATE TABLE dbo.dim_customer (
  customer_ident INT IDENTITY(1, 1), 
  customer_id VARCHAR(20) NOT NULL, 
  customer_name VARCHAR(255) NOT NULL, 
  customer_city VARCHAR(255) NULL, 
  customer_country VARCHAR(255) NULL
)

CREATE TABLE dbo.dim_employee (
  employee_ident INT IDENTITY(1, 1), 
  employee_id INT NOT NULL, 
  employee_name VARCHAR(85) NOT NULL, 
  employee_city VARCHAR(255) NULL, 
  employee_country VARCHAR(255) NULL
)


CREATE TABLE dbo.dim_time (
   time_member_key  INT NOT NULL ,
   calendar_date_dt  DATETIME NOT NULL ,
   calendar_day_of_week_num  INT NOT NULL ,
   calendar_day_of_week_name  VARCHAR(15) NOT NULL ,
   calendar_day_of_month_num  INT NOT NULL ,
   calendar_day_of_year_num  INT NOT NULL ,
   calendar_week_num  INT NOT NULL ,
   calendar_month_num  INT NOT NULL ,
   calendar_month_name  VARCHAR (15) NOT NULL ,
   calendar_quarter_num  INT NOT NULL ,
   calendar_year_num  INT NOT NULL 
) 


CREATE TABLE fact_sales (
  customer_ident INT NOT NULL, 
  product_ident INT NOT NULL, 
  employee_ident INT NOT NULL, 
  supplier_ident INT NOT NULL, 
  total_sale SMALLMONEY NOT NULL, 
  time_member_key INT NOT NULL
)

Next let’s populate these tables using the following queries:

-- supplier dimension:
INSERT dim_supplier ( 
  supplier_id , 
  supplier_name , 
  supplier_city , 
  country )
SELECT 
  supplierid, 
  companyname, 
  city, 
  country
FROM suppliers

-- product dimension:
INSERT dim_product (
  product_id, 
  product_name, 
  discontinued)
SELECT 
  productid, 
  productname,
  discontinued
FROM products

-- customer dimension:
INSERT dim_customer (
  customer_id, 
  customer_name, 
  customer_city, 
  customer_country)
SELECT
  customerid, 
  companyname, 
  city, 
  country
FROM customers

-- employee dimension:
INSERT dim_employee (
  employee_id, 
  employee_name, 
  employee_city, 
  employee_country)
SELECT
  employeeid, 
  TItleOfCourtesy + ’ ’ + FirstName + ’ ’ + LastName AS employee_name, 
  city, 
  country
FROM employees

Notice that dim_time is a special dimension. It isn’t populated by data that is already in the warehouse. Instead we populate it with calendar dates and date parts (day, month, quarter, year, and so forth) so that we can aggregate warehouse data as needed. You can come up with a routine that populates your own time dimension; here is a sample store procedure that I use to populate the time dimension:

CREATE PROCEDURE load_dim_time (
  @dim_table_name VARCHAR(255), 
  @start_date_dt SMALLDATETIME, 
  @end_date_dt SMALLDATETIME
)
AS
SET NOCOUNT ON 
DECLARE
  @sql_string NVARCHAR(1024)
  , @time_member_key INT
  , @calendar_date_dt SMALLDATETIME
  , @calendar_day_of_week_num INT
  , @calendar_day_of_week_name VARCHAR(10)
  , @calendar_day_of_month_num INT
  , @calendar_day_of_year_num INT
  , @calendar_week_num INT
  , @calendar_month_num INT
  , @calendar_month_name VARCHAR(10)
  , @calendar_quarter_num INT
  , @calendar_year_num INT

SET @calendar_date_dt = @start_date_dt
WHILE (@calendar_date_dt <= @end_date_dt) 
  BEGIN
  IF NOT EXISTS
    (
    SELECT  time_member_key
    FROM  dim_time
    WHERE  calendar_date_dt = @calendar_date_dt
    )
  BEGIN
    SELECT
      @calendar_day_of_week_num = DATEPART(dw, @calendar_date_dt)
      , @calendar_day_of_week_name = DATENAME(WEEKDAY, @calendar_date_dt)
      , @calendar_day_of_month_num = DATEPART(DD, @calendar_date_dt)
      , @calendar_day_of_year_num = DATEPART(DY, @calendar_date_dt)
      , @calendar_week_num = DATEPART(WK, @calendar_date_dt)
      , @calendar_month_num = DATEPART(M, @calendar_date_dt)
      , @calendar_month_name = DATENAME(MONTH, @calendar_date_dt)
      , @calendar_quarter_num = DATEPART(QQ, @calendar_date_dt)
      , @calendar_year_num = DATEPART(YYYY, @calendar_date_dt)
      , @time_member_key =
          CAST(
            CAST(@calendar_year_num AS VARCHAR) +
            RIGHT(’00’ + CAST(@calendar_day_of_year_num AS VARCHAR), 3)
          AS INT)
    SELECT @sql_string =
      ’INSERT INTO ’ + @dim_table_name +
      ’ (’ +
      ’time_member_key, ’ +
      ’calendar_date_dt, ’ +
      ’calendar_day_of_week_num,’ +
      ’calendar_day_of_week_name,’ +
      ’calendar_day_of_month_num,’ +
      ’calendar_day_of_year_num,’ +
      ’calendar_week_num,’ +
      ’calendar_month_num,’ +
      ’calendar_month_name,’ +
      ’calendar_quarter_num, ’ +
      ’calendar_year_num’ +
      ’) ’ +
      ’VALUES ’ +
      ’(’ +
      CHAR(39) + CAST(@time_member_key AS VARCHAR) + CHAR(39) + ’,’ +
      CHAR(39) + CAST(@calendar_date_dt AS VARCHAR) + CHAR(39) + ’,’ +
      CAST(@calendar_day_of_week_num AS VARCHAR) + ’,’ +
      CHAR(39) + @calendar_day_of_week_name + CHAR(39) + ’,’ +
      CAST(@calendar_day_of_month_num AS VARCHAR) + ’,’ +
      CAST(@calendar_day_of_year_num AS VARCHAR) + ’,’ +
      CAST(@calendar_week_num AS VARCHAR) + ’,’ +
      CAST(@calendar_month_num AS VARCHAR) + ’,’ +
      CHAR(39) + @calendar_month_name + CHAR(39) + ’,’ +
      CAST(@calendar_quarter_num AS VARCHAR) + ’,’ +
      CAST(@calendar_year_num AS VARCHAR) + ’)’

    EXEC sp_executesql @sql_string
  END

SET @calendar_date_dt = @calendar_date_dt + 1
END

/* now use load_dim_time procedure to populate dim_time table with needed dates */

EXEC load_dim_time dim_time, ’1/1/96’, ’1/1/99’

SQL Server has a fine ETL tool—Data Transformation Services (DTS)—which you can leverage to execute and schedule DW population routines. A typical DTS package determines which data rows need to be extracted from their source and inserts such rows into appropriate dimension and fact tables. Because this is a sample application, I won’t need to create any DTS packages, but keep in mind that real-world ETL routines can get quite complicated and might take several weeks to develop.

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020