Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
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# | Month | Year |
1 | A | Jan | 2017 |
1 | A | Mar | 2017 |
1 | A | Mai | 2017 |
1 | B | Jan | 2016 |
2 | A | May | 2017 |
New Table | |||
Project# | Order# | Month | Year |
1 | A | Jan | 2017 |
1 | A | Feb | 2017 |
1 | A | Mar | 2017 |
1 | A | Apr | 2017 |
1 | A | Mai | 2017 |
1 | B | Jan | 2016 |
2 | A | May | 2017 |
Solved! Go to Solution.
Hi @Anonymous,
First, please add a conditional column in original table (suppose it's 'Test_2') in query editor mode.
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] ) )
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]
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] )
Best regards,
Yuliana Gu
Hi @Anonymous,
First, please add a conditional column in original table (suppose it's 'Test_2') in query editor mode.
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] ) )
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]
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] )
Best regards,
Yuliana Gu
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
58 | |
55 | |
55 | |
37 | |
30 |
User | Count |
---|---|
78 | |
64 | |
45 | |
42 | |
40 |