PowerPivot performance issue with normalized model

cr731

Well-known Member
Joined
Sep 17, 2010
Messages
611
I'm having a performance issue with my data model and trying to figure out if it's just a bad design or if there is some solution that I'm missing.

My model consists of a fact table containing Customer Code, Product Code, Value Type (i.e. Volume, Revenue, Cost), Value, and a few attributes (i.e. market, geography, etc.) like below

Product Code
Customer Code
Value Type
Value
Market Code
Geography Code
Prod1
Cust1
Revenue
100
AA
US1
Prod2
Cust1
Revenue
200
BB
US2
Prod3
Cust2
Revenue
50
CC
US3
etc.

<tbody>
</tbody>


This table is 1.9 million rows.

Then, I have related dimension tables, relating to the Customer, Product, and each Attribute column of the fact table.

The largest of the dimension tables are Customer (6,000 rows) and Product (1,400 rows) - the rest are only a few hundred rows.

I have measures written to sum based on the Value Type, for instance

= CALCULATE( SUM( Fact[Value] ), Fact[Value Type] = "Revenue" )

Now, if I drag in my customer from the Customer dimension table into a pivot, it calculates my measures near instantly.

If I then add Product from the Product table, it completely hangs and runs out of memory or else takes an excessively long time to run (minutes, way too long for an average user to wait).

I assume this is because PowerPivot is calculating for every possible combination of Customer x Product (6,000 x 1,400 = 8.4M combinations).

This much be a common issue with models like this and wondering how do I overcome this? I prefer not to flatten the entire model into one table as I have many dimension levels that are much cleaner to view on their own. But as it stands, it basically is inoperable if trying to view Customer + Product combination level of detail.

Am I missing something here?

Thanks
 
Last edited:

Excel Facts

When they said...
When they said you are going to "Excel at life", they meant you "will be doing Excel your whole life".
Are you saying that you are adding product to the pivot table while customer is still in the pivot? If so, Power Pivot is not your problem. The problem is you are asking Excel to render 8.4 million values into a sheet.

The principle is to only render the numbers you want to look at instead of extracting them all just in case you might want to look at them later. It is a bit like you going to the web and searching for a phone number, but the browser tries to send you every phone number in the world. That will obviously take a lot longer.

your data model design looks excellent to me.
 
Last edited:
Upvote 0
Thanks for the response.

I'm not actually expecting Excel to return 8.4 million rows - there are 90,000 unique combinations of customer/product in the fact table, but within that, there are 6,000 unique customers and 1,400 unique products, so that's where I was thinking it was trying to calculate every possible combination since I'm adding the fields from the customer/product tables, not the fact table (based on reading this: AutoExist, Cross Table Filtering, and You - PowerPivotPro).

I do agree with you that the purpose of the pivot is to provide summary level information, I'm just trying to anticipate what a user might do and want to avoid having the file crash.
 
Upvote 0
OK. But the point is that it is the rendering of the answers that is the issue, not Power Pivot. For a demo, write this measure and put it in a pivot table (with nothing on rows or columns)

=sumx(summarize(fact,dimCust[customer number], dimProduct[product code]),fact[value])

This formula will iterate over every possible combination of customer and product (8 million rows) and add up the value column. See how long it takes when it is only asked to render a single value as the result.
 
Upvote 0

Forum statistics

Threads
1,214,987
Messages
6,122,614
Members
449,091
Latest member
gaurav_7829

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top