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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
mia23719
New Member

Data transformation based on multiple (calculated) criteria

Hello! 

 

I am looking to transform some invoice level data (where each row = 1 invoice) into a table showing spend per product per customer over time.

 

I'm confident there is some way to do this using a combination of unpivot & offset in power query, but as the # unpivoted rows required in each instance will vary (the contract duration and billing frequency varies per invoice) it is proving tricky.

 

To illustrate, here is a simplified version of the data I currently have: 

mia23719_2-1733922868931.png

 

And below is the format I would like to transform it into:

mia23719_3-1733922929796.png

 

Ultimately, what I would like to be able to do is calculate revenue generated per customer and per product (monthly) over time. 

 

If anyone knows how to get to the intended output, or could suggest a better way to do the analysis, I would very much appreciate the help! 

 

Thanks in advance 🙂

 

3 REPLIES 3
v-linhuizh-msft
Community Support
Community Support

Thanks for the replies from danextian and DataNinja777.

 

Hi @mia23719 ,

 

From your description I created simple tables:

vlinhuizhmsft_10-1733987474865.png

vlinhuizhmsft_9-1733987450224.png

 

1. Create the same index for the two tables above, I'm creating 1 here:

vlinhuizhmsft_7-1733987077555.png

2. Merge two tables as a new table.

vlinhuizhmsft_0-1733986578419.png

 

3. In the merged table, expand the column1 field.

vlinhuizhmsft_1-1733986621384.png

 

4. Create a custom column.

vlinhuizhmsft_2-1733986706698.png

 

 

= if [Billing] = "Monthly" then
    if [Date.Column1] >= [Simplified Start Date] and [Date.Column1] <= Date.AddMonths([Simplified Start Date], Number.FromText(Text.Start([Contract Duration], 2))) then
        [#"Billing Amount (£)"]
    else
        0
else if [Billing] = "Annually" then
    if [Date.Column1] = [Simplified Start Date] or [Date.Column1] = Date.AddMonths([Simplified Start Date], Number.FromText(Text.Start([Contract Duration], 2))) then
        [#"Billing Amount (£)"]
    else
        0
else
    0

 

 

 

5. Perform a pivot operation.

vlinhuizhmsft_3-1733986806273.png

6. You can remove the unneeded columns.

Result:

vlinhuizhmsft_4-1733986841819.png

 

Best Regards,
Zhu
Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly.

DataNinja777
Super User
Super User

Hi @mia23719 ,

 

For analyzing contracts with variable durations and start and end dates, I recommend using DAX instead of Power Query (M). There are multiple ways to achieve the desired output using DAX, and one of the approaches is outlined below:

  1. Create a disconnected calendar table:

 

DataNinja777_0-1733927842546.png

2. Write a dax formula like below:

Total billing amount = 
VAR BillingAmountPerRow = 
    ADDCOLUMNS(
        VALUES('Calendar'[yyyy-mm]),
        "BillingAmount",
        CALCULATE(
            SUMX(
                'Contract Revenue',
                IF(
                    'Contract Revenue'[Start Date] <= MAX('Calendar'[Date]) &&
                    'Contract Revenue'[End Date] >= MIN('Calendar'[Date]),
                    'Contract Revenue'[Billing amount],
                    BLANK()
                )
            )
        )
    )
RETURN
SUMX(BillingAmountPerRow, [BillingAmount])

 

3. Visualize in a matrix visual:

DataNinja777_1-1733927928480.png

You can rearrange the rows and columns to achieve your desired output.  I have attached an example pbix file for your reference.

 

Best regards,

 

 

 

 

danextian
Super User
Super User

Hi @mia23719 

Why  would you want to transform your data wihch is in a better shape into that format? You'll end up creating a measure for each month and you won't be able to slice and dice. You will need to generate several row of dates for those with monthly billing and then just two for annually which can be fairly easily done with Power Query and then just use a matrix viz to get the desired look.

 

That said, we would need a workable sample data and not an image. A link to an Excel file in the cloud will do.










Did I answer your question? Mark my post as a solution!


Proud to be a Super User!









"Tell me and I’ll forget; show me and I may remember; involve me and I’ll understand."
Need Power BI consultation, get in touch with me on LinkedIn or hire me on UpWork.
Learn with me on YouTube @DAXJutsu or follow my page on Facebook @DAXJutsuPBI.

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.