Business Intelligence Blogs

View blogs by industry experts on topics such as SSAS, SSIS, SSRS, Power BI, Performance Tuning, Azure, Big Data and much more! You can also sign up to post your own business intelligence blog.

«October 2015»

Data Warehouse from the Ground Up at SQL Saturday Orlando, FL on Oct. 10th

SQL Saturday #442SQL Saturday #442 is upon us and yours truly will be presenting in Orlando, Florida on October 10th alongside Mitchell Pearson (b|t). The session is scheduled at 10:35 AM and will last until 11:35 AM. I’m very excited to be presenting at SQL Saturday Orlando this year as it’ll be my first presenting this session in person and my first time speaking at SQL Saturday Orlando! If you haven’t registered yet for this event, you need to do that. This event will be top notch!

My session is called Designing a Data Warehouse from the Ground Up. What if you could approach any business process in your organization and quickly design an effective and optimal dimensional model using a standardized step-by-step method? In this session I’ll discuss the steps required to design a unified dimensional model that is optimized for reporting and follows widely accepted best practices. We’ll also discuss how the design of our dimensional model affects a SQL Server Analysis Services solution and how the choices we make during the data warehouse design phase can make or break our SSAS cubes. You may remember that I did this session a while back for Pragmatic Works via webinar. I’ll be doing the same session at SQL Saturday Orlando but on-prem! ;)

So get signed up for this event now! It’s only 11 days away!

Read more

Create Date Dimension with Fiscal and Time

Here are three scripts that create and Date and Time Dimension and can add the fiscal columns too. First run the Dim Date script first to create the DimDate table. Make sure you change the start date and end date on the script to your preference. Then run the add Fiscal Dates scripts to add the fiscal columns. Make sure you alter the Fiscal script to set the date offset amount. The comments in the script will help you with this.

This zip file contains three SQL scripts.

Create Dim Date

Create Dim Time

Add Fiscal Dates

These will create a Date Dimension table and allow you to run the add fiscal script to add the fiscal columns if you desire. The Create Dim Time will create a time dimension with every second of the day for those that need actual time analysis of your data.

Make sure you set the start date and end date in the create dim date script. Set the dateoffset in the fiscal script.

Download the script here:


Read more

An other Example of Calculation-Dimension

  • 30 August 2010
  • Author: Qazafi Anjum Syed
  • Number of views: 20482

Recently one of my clients would like to see their Revenue figures represented some of the time as a positive (+VE) value and some time as a negative (-VE) value. They would like to have the ability to select between the two at run time in the Analyses Services Cube. The users are using Excel 2007 as the client tool for reporting. They do not want to change the figures inside the source database but would instead like to apply a mask at runtime. There are some specific post codes which are dedicated to Revenue; this enables revenue transactions to be indentified

In order to achieve this I have created a dummy dimension, similar to a ‘time utility dimension' (also known as a ‘date tool' dimension or a ‘shell' dimension. I had advice from Chris Webb regarding this, he also referred me the book ‘Expert Cube Development with SQL Server Analysis Services 2008') and then add a calculated member to it with two values.

We do not need to create a table in our Data warehouse for this purpose; we can create a view some thing like this

CREATE VIEW RevenueAsPositive AS
SELECT 0 AS ID, 'Convert Revenue to Positive' AS Description
SELECT 1 AS ID, 'Stay Revenue as Negative' AS Description
Now we need to add this view inside our DSV and create a dimension based on this view
Alternatively we can create some thing like this inside our DSV




So this dimension has two values

1. Convert Revenue to Positive --> 0
2. Stay Revenue as Negative --> 1



After creating this dimension now you need to set the properties of the attribute hierarchy

  • Set "DefaultMember" to ‘Stay Revenue as Negative', as below:


•Set the “IsAggregatable” property to “False”, so there’s no All Member on the attribute hierarchy, as below:


In the following picture you can see all the revenue figures are negative, which is the default behavior we have defined inside the Analyses Services Cube



If now the user would like to convert the revenue figures to display as positive, they need to set the report filter to Convert Revenue to Positive as shown in the following figure:

In order to achieve this functionality you need to use a scoped assignment using MDX that's something like this:

When the user chooses "Convert Revenue to Positive" than I multiplied all actual measure values by -1, using this MDX:

SCOPE([Convert Revenue To Positive].[Convert Revenue To Positive].&[0],descendants([Dimension POST CODE].[Post Code Structure].[PC Level 2].&[IREV],[Dimension POST CODE].[Post Code Structure].[Post Code],self_and_before),[Measures].[YTD Actuals]
This =(([Dimension POST CODE].[Post Code Structure].currentmember)*(-1));

SCOPE([Convert Revenue To Positive].[Convert Revenue To Positive].&[0],descendants([Dimension POST CODE].[Post Code Structure].[PC Level 2].&[EREV],[Dimension POST CODE].[Post Code Structure].[Post Code],self_and_before),[Measures].[YTD Actuals]
This =(([Dimension POST CODE].[Post Code Structure].currentmember)*(-1));

Notice that the "Profit and Loss" values do not change even though the Revenue values have changed to positive. This is achieved through the following SCOPE statement:

SCOPE([Convert Revenue To Positive].[Convert Revenue To Positive].&[0],[Dimension POST CODE].[Post Code Structure].[PC Level 1].&[PL],[Measures].[YTD Actuals]
This =(([Dimension POST CODE].[Post Code Structure].&[EEXP])+[Dimension POST CODE].[Post Code Structure].&[IEXP]-[Dimension POST CODE].[Post Code Structure].&[IREV]-[Dimension POST CODE].[Post Code Structure].&[EREV]);

Hopefully this will help you if you are trying to build some similar functionality.

Finally, I would like to acknowledge and thank Chris Webb for his suggestions and support, thank you Chris.

Categories: Analysis Services
Rate this article:
No rating

Please login or register to post comments.