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

Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now

Reply
Anonymous
Not applicable

How to make a new table based on entries from an old table, but with one line per month per project?

I am fairly new to Power BI.

I want to generate a new table based on entries from an old table. The new table should hold one line per month per project and order number for the time perriod listed in the old table. I made a dummy table to illustrate the problem. How to do this?

Thank you in advanced for your input!

 

Old Table   
Project#Order#MonthYear
1AJan2017
1AMar2017
1AMai2017
1BJan2016
2AMay2017
    
New Table  
Project#Order#MonthYear
1AJan2017
1AFeb2017
1AMar2017
1AApr2017
1AMai2017
1BJan2016
2AMay2017
1 ACCEPTED SOLUTION
v-yulgu-msft
Microsoft Employee
Microsoft Employee

Hi @Anonymous,

 

First, please add a conditional column in original table (suppose it's 'Test_2') in query editor mode.

1.PNG

 

In data view mode, create below summarized table with DAX:

Test_3 =
SUMMARIZE (
    Test_2,
    Test_2[Project#],
    Test_2[Order#],
    Test_2[Year],
    "StartMonth", MIN ( Test_2[MonthNumber] ),
    "EndMonth", MAX ( Test_2[MonthNumber] )
)

2.PNG

 

Create a calendar table and add Year, Month columns to it.

calendar TB =
FILTER (
    CALENDAR ( DATE ( 2016, 1, 1 ), DATE ( 2017, 12, 31 ) ),
    DAY ( [Date] ) = 1
)

MonthName in Calen = [Date].[Month]
MonthNo in Calen = [Date].[MonthNo]
Year in Calen = [Date].[Year]

3.PNG

 

Cross join above two tables.

Test_4 =
SELECTCOLUMNS (
    FILTER (
        CROSSJOIN ( Test_3, 'calendar TB' ),
        'calendar TB'[MonthNo in Calen] >= Test_3[StartMonth]
            && 'calendar TB'[MonthNo in Calen] <= Test_3[EndMonth]
            && Test_3[Year] = 'calendar TB'[Year in Calen]
    ),
    "Project#", [Project#],
    "Order#", [Order#],
    "Month", [MonthName in Calen],
    "Year", [Year]
)

4.PNG

 

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

2 REPLIES 2
v-yulgu-msft
Microsoft Employee
Microsoft Employee

Hi @Anonymous,

 

First, please add a conditional column in original table (suppose it's 'Test_2') in query editor mode.

1.PNG

 

In data view mode, create below summarized table with DAX:

Test_3 =
SUMMARIZE (
    Test_2,
    Test_2[Project#],
    Test_2[Order#],
    Test_2[Year],
    "StartMonth", MIN ( Test_2[MonthNumber] ),
    "EndMonth", MAX ( Test_2[MonthNumber] )
)

2.PNG

 

Create a calendar table and add Year, Month columns to it.

calendar TB =
FILTER (
    CALENDAR ( DATE ( 2016, 1, 1 ), DATE ( 2017, 12, 31 ) ),
    DAY ( [Date] ) = 1
)

MonthName in Calen = [Date].[Month]
MonthNo in Calen = [Date].[MonthNo]
Year in Calen = [Date].[Year]

3.PNG

 

Cross join above two tables.

Test_4 =
SELECTCOLUMNS (
    FILTER (
        CROSSJOIN ( Test_3, 'calendar TB' ),
        'calendar TB'[MonthNo in Calen] >= Test_3[StartMonth]
            && 'calendar TB'[MonthNo in Calen] <= Test_3[EndMonth]
            && Test_3[Year] = 'calendar TB'[Year in Calen]
    ),
    "Project#", [Project#],
    "Order#", [Order#],
    "Month", [MonthName in Calen],
    "Year", [Year]
)

4.PNG

 

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.
Anonymous
Not applicable

Thank you @v-yulgu-msft. This worked perfectly!

Helpful resources

Announcements
OCT PBI Update Carousel

Power BI Monthly Update - October 2024

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

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

October NL Carousel

Fabric Community Update - October 2024

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