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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Pillz
Frequent Visitor

Get last 6 months in DAX with limited data

My current example dataset I'm working is below:

Event NameDateType
Event 113-Apr-20In Person
Event 25-May-20Online
Event 321-Jun-20Online
Event 45-Feb-20In Person
Event 524-Feb-20Online

 

I'm trying to use DAX to create a table that shows # of events across last 6 months similar to below. However without data on July/August, I'm not sure how to create columns to those 2 months. Is there any way I can create the table using these constraints?

 

 Feb-20Mar-20Apr-20May-20Jun-20Jul-20Aug-20
In Person1010000
Online1001100

 

1 ACCEPTED SOLUTION
Icey
Community Support
Community Support

Hi @Pillz ,

 

If you want to display the last 6 months in the table. You can try to create a calendar table. There are two ways to achieve its functionality: implemented with a filter or implemented in a table.

 

1. implemented in a filter:

a. You can create a calendar table like below and then sort [MonthName-Year] column by [Month-Year] column.

 

Calendar = 
ADDCOLUMNS (
    CALENDAR ( DATE ( 2019, 1, 1 ), DATE ( 2020, 12, 31 ) ),
    "Month", MONTH ( [Date] ),
    "Year", YEAR ( [Date] )
)
MonthName = FORMAT ( 'Calendar'[Date], "mmm" )
MonthName-Year = 'Calendar'[MonthName] & "-" & 'Calendar'[Year]
Month-Year = 'Calendar'[Month] & "-" & 'Calendar'[Year]

 

sort.jpg

 

b. Create relationships between the two tables.

relation.jpg

 

c. Create a measure.

 

count = COUNTROWS('Table')+0

 

 

d. Create a Matrix visual and set a filter on the visual.

matrix1.PNG

 

 

2. implemented in a table:

You can just create a dynamic calendar table containing only the dates of the previous 6 months based on today's date.

 

Last 6 months = 
ADDCOLUMNS (
    CALENDAR ( EOMONTH ( TODAY (), -7 ) + 1, EOMONTH ( TODAY (), 0 ) ),
    "Month", MONTH ( [Date] ),
    "Year", YEAR ( [Date] )
)
MonthName = FORMAT('Last 6 months'[Date],"mmm")
MonthName-Year = 'Last 6 months'[MonthName]&"-"&'Last 6 months'[Year]
Month-Year = 'Last 6 months'[Month]&"-"&'Last 6 months'[Year]

 

 

And then, follow the steps of the previous method. However, there is no need to filter on date.

matrix2.PNG

 

For more details, please check the attached .pbix file.

 

 

Best Regards,

Icey

 

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
Icey
Community Support
Community Support

Hi @Pillz ,

 

If you want to display the last 6 months in the table. You can try to create a calendar table. There are two ways to achieve its functionality: implemented with a filter or implemented in a table.

 

1. implemented in a filter:

a. You can create a calendar table like below and then sort [MonthName-Year] column by [Month-Year] column.

 

Calendar = 
ADDCOLUMNS (
    CALENDAR ( DATE ( 2019, 1, 1 ), DATE ( 2020, 12, 31 ) ),
    "Month", MONTH ( [Date] ),
    "Year", YEAR ( [Date] )
)
MonthName = FORMAT ( 'Calendar'[Date], "mmm" )
MonthName-Year = 'Calendar'[MonthName] & "-" & 'Calendar'[Year]
Month-Year = 'Calendar'[Month] & "-" & 'Calendar'[Year]

 

sort.jpg

 

b. Create relationships between the two tables.

relation.jpg

 

c. Create a measure.

 

count = COUNTROWS('Table')+0

 

 

d. Create a Matrix visual and set a filter on the visual.

matrix1.PNG

 

 

2. implemented in a table:

You can just create a dynamic calendar table containing only the dates of the previous 6 months based on today's date.

 

Last 6 months = 
ADDCOLUMNS (
    CALENDAR ( EOMONTH ( TODAY (), -7 ) + 1, EOMONTH ( TODAY (), 0 ) ),
    "Month", MONTH ( [Date] ),
    "Year", YEAR ( [Date] )
)
MonthName = FORMAT('Last 6 months'[Date],"mmm")
MonthName-Year = 'Last 6 months'[MonthName]&"-"&'Last 6 months'[Year]
Month-Year = 'Last 6 months'[Month]&"-"&'Last 6 months'[Year]

 

 

And then, follow the steps of the previous method. However, there is no need to filter on date.

matrix2.PNG

 

For more details, please check the attached .pbix file.

 

 

Best Regards,

Icey

 

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

parry2k
Super User
Super User

@Pillz you should create a measure like this

 

Count = COUNTROWS ( Table ) + 0

 

and then use this measure in the matrix.

 

I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos whoever helped to solve your problem. It is a token of appreciation!

Visit us at https://perytus.com, your one-stop-shop for Power BI-related projects/training/consultancy.



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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