Skip to content

Instantly share code, notes, and snippets.

@Matticusau
Created July 1, 2020 22:58
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save Matticusau/3eb0a4aaeab671165464d9f21e84afd2 to your computer and use it in GitHub Desktop.
Save Matticusau/3eb0a4aaeab671165464d9f21e84afd2 to your computer and use it in GitHub Desktop.
A DAX query to add a fiscal calendar to your PowerBI dataset.
Fiscal Calendar =
// based on https://guyinacube.com/2018/02/13/power-bi-date-table-create-using-dax/
VAR BaseCalendar = CALENDAR("01/01/2010", "01/01/2025")
RETURN
GENERATE(
BaseCalendar,
VAR BaseDate = [Date]
VAR YearDate = Year(BaseDate)
VAR MonthNumber = MONTH(BaseDate)
VAR FiscalYearLong = IF (MonthNumber <= 6, INT(FORMAT(BaseDate, "yyyy")), INT(FORMAT(BaseDate, "yyyy")) + 1)
VAR FiscalYear = CONCATENATE("FY", RIGHT(IF (MonthNumber <= 6, VALUE(FORMAT(BaseDate, "yyyy")), VALUE(FORMAT(BaseDate, "yyyy")) + 1), 2))
VAR FiscalHalf = CONCATENATE("H", IF (MonthNumber <= 6, 2, 1))
VAR FiscalQuarter = CONCATENATE("Q", IF (MonthNumber <= 3, 3, IF (MonthNumber > 3 && MonthNumber <= 6, 4, IF (MonthNumber > 6 && MonthNumber <= 9, 1, 2 ))))
VAR FiscalYearMonthNum_tmp = IF (MonthNumber <= 6, INT(FORMAT(BaseDate, "mm")) + 6, INT(FORMAT(BaseDate, "mm")) - 6)
VAR FiscalYearMonthNum = IF (FiscalYearMonthNum_tmp <= 9, CONCATENATE("0", FiscalYearMonthNum_tmp), FiscalYearMonthNum_tmp)
RETURN ROW (
"_DateKey", FORMAT (BaseDate, "yyyymmdd"),
"Year", YearDate,
"Month Number", MonthNumber,
"Month Name", FORMAT ( BaseDate, "mmmm"),
"Day", DAY(BaseDate),
"Weekday Short", FORMAT( BaseDate, "ddd"),
"Weekday", FORMAT( BaseDate, "dddd"),
"Year Month", FORMAT ( BaseDate, "mmm yy"),
"Fiscal Year", FiscalYear,
"Fiscal Quarter", FiscalQuarter,
"Fiscal Half", FiscalHalf,
"Fiscal Year Quarter", CONCATENATE(FiscalYear, CONCATENATE(" ", FiscalQuarter)),
"Fiscal Year Half", CONCATENATE(FiscalYear, CONCATENATE(" ", FiscalHalf)),
"Fiscal Year Month", CONCATENATE(FiscalYear, CONCATENATE(" ", FORMAT ( BaseDate, "mmmm"))),
"Fiscal Year Month Sort", CONCATENATE(FiscalYear, CONCATENATE(" ", FiscalYearMonthNum)),
"_Current Day Flag", IF ( DAY(BaseDate) = DAY(NOW()), "Y", "N"),
"Current Month", IF (YEAR(NOW()) = YEAR(BaseDate) && MONTH(BaseDate) = MONTH(NOW()), "Y", "N"),
"Current Quater", IF (YEAR(NOW()) = YEAR(BaseDate) && (
MONTH(NOW()) <= 3 && MonthNumber <= 3), "Y", IF (YEAR(NOW()) = YEAR(BaseDate) && (
MONTH(NOW()) > 3 && MONTH(NOW()) <= 6 && MonthNumber > 3 && MonthNumber <= 6), "Y", IF (YEAR(NOW()) = YEAR(BaseDate) && (
MONTH(NOW()) > 6 && MONTH(NOW()) <= 9 && MonthNumber > 6 && MonthNumber <= 9), "Y", IF (YEAR(NOW()) = YEAR(BaseDate) && (
MONTH(NOW()) > 9 && MONTH(NOW()) <= 12 && MonthNumber > 9 && MonthNumber <= 12), "Y", "N")
)
))))
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment