Join us for an expert-led overview of the tools and concepts you'll need to pass exam PL-300. The first session starts on June 11th. See you there!
Get registeredPower BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.
Hi All,
I need to create a Date Table [Data Table] using any possible DAX measures or DAX calculated columns. I need the output in the below expected format.Please suggest.
so I basically want to show current month, year, previous month along with the month start and end dates. I want it for the whole year for 2021,2022 and 2023..Please suggest
Current Month | Year | CurrentMonthStart | CurrentMonthEnd | Previous Month | PreviousMonthStart | PreviousMonthEnd |
January | 2022 | 01-01-2022 | 31-01-2022 | December | 01-12-2021 | 31-12-2021 |
February | 2022 | 01-02-2022 | 28-02-2022 | January | 01-01-2022 | 31-01-2022 |
March | 2022 | 01-03-2022 | 31-03-2022 | February | 01-02-2022 | 28-02-2022 |
April | 2022 | 01-04-2022 | 30-04-2022 | March | 01-03-2022 | 31-03-2022 |
May | 2022 | 01-05-2022 | 31-05-2022 | April | 01-04-2022 | 30-04-2022 |
Solved! Go to Solution.
@deb_power123 , Try like
Date2 = var _1 = ADDCOLUMNS( CALENDAR(date(2019,01,01), date(2021,12,31) ), "Year", year([date]) , "Month Start Date", eomonth([date],-1)+1, "Month End Date", eomonth([date],0), "Month", format([DAte],"MMMM"), "Previous Month Start Date", eomonth([date],-2)+1, "Previous Month End Date", eomonth([date],-1), "Previous Month", format(eomonth([date],-1),"MMMM"))
return SUMMARIZE(_1,[Year],[Month Start Date],[Month End Date],[Month],[Previous Month],[Previous Month Start Date],[Previous Month End Date])
if needed you can simply return _1 , no need of summarize
New columns
Month Year = FORMAT([Date],"mmm-yyyy")
Month Year sort = FORMAT([Date],"yyyymm")
Start Month date= eomonth([Date],-1)+0
Start End date= eomonth([Date],-1)+0
Month Type = Switch( True(),
eomonth([Date],0) = eomonth(Today(),-1),"Last Month" ,
eomonth([Date],0)= eomonth(Today(),0),"This Month" ,
Format([Date],"MMM-YYYY")
)
For measures, you can refer
Power BI — Month on Month with or Without Time Intelligence
Power BI — Month on Month with or Without Time Intelligence
https://medium.com/@amitchandak.1978/pow...
refer if needed
Power BI for Beginners - DAX Calendar - Standard Calendar, Non-Standard Calendar, 4-4-4 Calendar
https://www.youtube.com/watch?v=IsfCMzjKTQ0&t=145s
Power BI for Beginners - Time Intelligence, DATESMTD, DATESQTD, DATESYTD, Week On Week, Week Till Date, Custom Period on Period,
Custom Period till date: https://youtu.be/aU2aKbnHuWs&t=145s
Hi @amitchandak It doesnt work, it doesnt fetch the output expected.You try the formula in pbix,it wont fetch the desired answer
@deb_power123 , Try a new table like
Table = ADDCOLUMNS( GENERATESERIES(1,12,1), "Year", year(Today()) , "Month Start Date", Date(Year(today()),[Value],1), "Month End Date", eomonth(Date(Year(today()),[Value],1),0) , "Month", format(Date(Year(today()),[Value],1),"MMMM"), "Previous Month Start Date", eomonth(Date(Year(today()),[Value],1),-2)+1, "Previous Month End Date", eomonth(Date(Year(today()),[Value],1),-1) , "Previous Month", format( eomonth(Date(Year(today()),[Value],1),-2)+1,"MMMM"))
Hi @amitchandak If I want to show the data for 2019,2020 and 2021, what changes should I make to the above formula of yours?
At present it looks great but it calculates only for 2022 but I want to show 2019,2021 and 2020 data as well.Please suggest
@deb_power123 , Try like
Date2 = var _1 = ADDCOLUMNS( CALENDAR(date(2019,01,01), date(2021,12,31) ), "Year", year([date]) , "Month Start Date", eomonth([date],-1)+1, "Month End Date", eomonth([date],0), "Month", format([DAte],"MMMM"), "Previous Month Start Date", eomonth([date],-2)+1, "Previous Month End Date", eomonth([date],-1), "Previous Month", format(eomonth([date],-1),"MMMM"))
return SUMMARIZE(_1,[Year],[Month Start Date],[Month End Date],[Month],[Previous Month],[Previous Month Start Date],[Previous Month End Date])
if needed you can simply return _1 , no need of summarize
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 |
---|---|
14 | |
10 | |
10 | |
9 | |
9 |
User | Count |
---|---|
20 | |
13 | |
13 | |
11 | |
8 |