Power Pivot query

pjmorris

Well-known Member
Joined
Aug 2, 2012
Messages
2,158
Office Version
  1. 365
Platform
  1. Windows
I'm learning how to use the power pivot - which is an extraordinary improvement on normal pivottables. But I don't know the full capabilities. My challenge is this:

I have data arranged as follows (the real data is more complex):

ActivityStart DateEnd DateTotal Effort
A1 Jan 201831 Dec 201860
B1 Mar 201830 Sep 2018140
C1 Aug 201831 Dec 2018100

<tbody>
</tbody>

The output I would like to achieve would be:
JFMAMJJASOND
Effort5525252525254545252525

<tbody>
</tbody>

I think that PowerPivot could do something like this, but can't work out how. If someone let me know, authoratitivly, whether to persist with PP or whether I need to take a different approach I'd be grateful.

Many thanks

Peter
 

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
Hello pjmorris

what you are saying is achievable but you need to make some changes to your data. First of all you will need to create a Calendar Table

Second, you may need to modify the table you have posted, instead of having a start date and end date, I would keep just one date column and then duplicate each row N number of times depending on the time frame from Start Date to End Date

As an example, if you wanted to perform an analysis by month, the first row would become

Book1
ABC
1ActivtyDateEffort
2A1-Jan-185
3A1-Feb-185
4A1-Mar-185
5A1-Apr-185
6A1-May-185
7A1-Jun-185
8A1-Jul-185
9A1-Aug-185
10A1-Sep-185
11A1-Oct-185
12A1-Nov-185
13A1-Dec-185
Sheet1
 
Upvote 0
Hi

Many thanks for the reply. I'll follow up with the Calendar link. The challenge will be changing the source data as suggested - I can see why, but obviously need to automate that step as users will not do so and there are many to be changed. Any suggestions about how to do this would help.

Regards

Peter
 
Upvote 0
You could use power query to apply the transformation, it should be something like this:




Code:
let
    // source table, change it to a table coming from your database, or excel
    Source = Table.FromRows(
                    Json.Document(
                            Binary.Decompress(
                                   Binary.FromText(
                                        "i45WclTSUTLU9UrM0zW0ADKNDXVdUpMhbDMDpVidaCUnsArfxCKoCgPd4NQCCNvQBKLEGazEsTQd0xBDA6CSWAA=", 
                                        BinaryEncoding.Base64), 
                                    Compression.Deflate)), 
                            let _t = ((type text) meta [Serialized.Text = true]) in type table [Activity = _t, #"Start Date" = _t, #"End Date" = _t, #"Total Effort" = _t]),
    
    //  transformations
    ChangedType = Table.TransformColumnTypes(Source,{{"Activity", type text}, {"Start Date", type date}, {"End Date", type date}, {"Total Effort", Int64.Type}}),
    
    ModifyTotalEffort = Table.AddColumn( ChangedType, "TotEffort", each [Total Effort ] / Duration.Days( [End Date] - [Start Date] ) + 1 , type number ),
    
    AddDaysList = Table.AddColumn( ModifyTotalEffort, "Dates", each List.Dates([Start Date], Duration.Days( [End Date] - [Start Date] ) + 1, #duration(1, 0, 0, 0) ), type list ),
    
    ExpandedDates = Table.ExpandListColumn(AddDaysList, "Dates"),
    
    RemovedColumns = Table.RemoveColumns( ExpandedDates, {"Start Date", "End Date", "Total Effort"} )
in
    RemovedColumns
 
Upvote 0
Hi, I've been on this forum for ages and this has to be the most useful help I've received. Thank you so much.

Really appreciated.

Regards
 
Upvote 0
Hi,

Just thought I'd share my adaptation of the query which resulted in the month view I think I need:

Code:
let
    Source = Excel.CurrentWorkbook(){[Name="tblSource"]}[Content],


    ChangedType = Table.TransformColumnTypes(Source,{{"Activity", type text}, {"Start Date", type date}, {"End Date", type date}, {"Total Effort", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(ChangedType, "DurationMonths", each Date.Month([End Date])-Date.Month([Start Date])+1+12*(Date.Year([End Date])-Date.Year([Start Date]))),
    ModifyTotalEffort = Table.AddColumn(#"Added Custom", "TotEffort", each [Total Effort]/[DurationMonths]),
    
    AddDaysList = Table.AddColumn(ModifyTotalEffort, "Dates", each List.Dates([Start Date], Duration.Days( [End Date] - [Start Date] ) + 1, #duration(1, 0, 0, 0) ), type list),
    
    ExpandedDates = Table.ExpandListColumn(AddDaysList, "Dates"),
    UniqueMonthlyID = Table.AddColumn(ExpandedDates, "Custom", each (Date.Year([Dates])-2000)*100+Date.Month([Dates])),
    #"Removed Columns" = Table.RemoveColumns(UniqueMonthlyID,{"Start Date", "End Date", "Total Effort", "DurationMonths", "Dates"}),
    #"Removed Duplicates" = Table.Distinct(#"Removed Columns", {"Custom", "Activity"})
in
    #"Removed Duplicates"
 
Upvote 0

Forum statistics

Threads
1,214,657
Messages
6,120,769
Members
448,991
Latest member
Hanakoro

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