Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
JrobertsUK
New Member

Trying to recreate pivot table in Power Bi- Help

Hi All,


New to Power BI.

Loving it, but having an issue.


I am trying to recreate the below pivot table

Pivot table.JPG

The Total Aged Stock column is currently a sum in excel, adding various aging "buckets"

 

I am able to recreate the majority of the table in Power BI, with the exception of this one column.

BI Table.JPG
I believe this may be achiveable via measures or a calculated column, but am struggling to find a working solution.


Any help is appriciated, thanks all.

1 ACCEPTED SOLUTION
v-yulgu-msft
Employee
Employee

Hi @JrobertsUK,

 

Based on my assumption, I created a sample data table named as 'Test2'.

1.PNG

 

In above table, please create two calculated columns:

sum over 60 days =
CALCULATE (
    SUM ( 'Test 2'[Ages] ),
    FILTER (
        ALLEXCEPT ( 'Test 2', 'Test 2'[Customer NO] ),
        'Test 2'[Cat] <> "0-30 days"
            && 'Test 2'[Cat] <> "31-60 days"
    )
)

Sum total =
CALCULATE (
    SUM ( 'Test 2'[Ages] ),
    ALLEXCEPT ( 'Test 2', 'Test 2'[Customer NO] )
)

7.PNG

 

Then, create a calculated table like below:

summarize table =
UNION (
    SELECTCOLUMNS (
        'Test 2',
        "Customer NO", 'Test 2'[Customer NO],
        "Age", 'Test 2'[Ages],
        "Cat", 'Test 2'[Cat]
    ),
    SUMMARIZE (
        'Test 2',
        'Test 2'[Customer NO],
        "Age", AVERAGE ( 'Test 2'[sum over 60 days] ),
        "Cat", "Over 60 days"
    ),
    SUMMARIZE (
        'Test 2',
        'Test 2'[Customer NO],
        "Age", AVERAGE ( 'Test 2'[Sum total] ),
        "Cat", "Total"
    )
)

Add corresponding fields from above new table into matrix visual. Remember to turn off the "Column Total" under format panel.

6.PNG

 

To follow RolandsP's suggestion that use Drill Down as a workaround, please see below steps.

In report view, choose the [Cat] column, meanwhile, click the "New Group" button.

2.PNG

 

Set groups like below:

3.PNG

 

After than, you will get a new group column in original table. Add the new group to "Columns" section in Matrix visual.

4.PNG5.PNG

 

On top level, matrix show total values for "Over 60 days". When you click the highlighted drill down icon, matrix will show total values across all groups.

 

Best regards,

Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
v-yulgu-msft
Employee
Employee

Hi @JrobertsUK,

 

Based on my assumption, I created a sample data table named as 'Test2'.

1.PNG

 

In above table, please create two calculated columns:

sum over 60 days =
CALCULATE (
    SUM ( 'Test 2'[Ages] ),
    FILTER (
        ALLEXCEPT ( 'Test 2', 'Test 2'[Customer NO] ),
        'Test 2'[Cat] <> "0-30 days"
            && 'Test 2'[Cat] <> "31-60 days"
    )
)

Sum total =
CALCULATE (
    SUM ( 'Test 2'[Ages] ),
    ALLEXCEPT ( 'Test 2', 'Test 2'[Customer NO] )
)

7.PNG

 

Then, create a calculated table like below:

summarize table =
UNION (
    SELECTCOLUMNS (
        'Test 2',
        "Customer NO", 'Test 2'[Customer NO],
        "Age", 'Test 2'[Ages],
        "Cat", 'Test 2'[Cat]
    ),
    SUMMARIZE (
        'Test 2',
        'Test 2'[Customer NO],
        "Age", AVERAGE ( 'Test 2'[sum over 60 days] ),
        "Cat", "Over 60 days"
    ),
    SUMMARIZE (
        'Test 2',
        'Test 2'[Customer NO],
        "Age", AVERAGE ( 'Test 2'[Sum total] ),
        "Cat", "Total"
    )
)

Add corresponding fields from above new table into matrix visual. Remember to turn off the "Column Total" under format panel.

6.PNG

 

To follow RolandsP's suggestion that use Drill Down as a workaround, please see below steps.

In report view, choose the [Cat] column, meanwhile, click the "New Group" button.

2.PNG

 

Set groups like below:

3.PNG

 

After than, you will get a new group column in original table. Add the new group to "Columns" section in Matrix visual.

4.PNG5.PNG

 

On top level, matrix show total values for "Over 60 days". When you click the highlighted drill down icon, matrix will show total values across all groups.

 

Best regards,

Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
RolandsP
Resolver IV
Resolver IV

You need to run new grouping ( using New Groups) on your ageing column and classify it in 3 groups: 0-30 Days, 31-60 Days and Over 60 Days (this would include all your groups over 60 days). And then in the matrix, you would include two levels in columns - New Grouping column, and existing ageing column. Then you will be able to drill in first level group Over 60 days to show more granular breakdown. This would be a little bit different structure from Excel pivotable, but very close one.

Thanks for the rapid response Roland. I've tried to do this as per your instructions, but am struggling. Do you have any practical examples?

You need to do following steps:

1) Select the current grouping column 

2) Then you need to select New Group under Modelling tab.

Grouping 1.JPG

3) There from Ungrouped value you select current group 0-30 Days and press Group, then select 31-60 days and press Group, then select all remaining values holding CTRL and press Group. You can change the name for this new group. 

4) Now you have new column in the table that you can include in columns in matrix.

 

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.