Calendar (or date) table is crucial for performing date intelligence calculations in Power BI.
Normally, you would find a reasonable calendar table in most data models. But occasionally I come across models where there is no calendar table.
So I present to you, the ultimate & best way to generate calendar table using Power Query.
How to create the perfect calendar table with Power Query?
Start by creating a new “blank query” connection in Power BI.
Then use the =List.Dates() function to generate the dates you want.
For example, to get the calendar dates for year 2025 use below code:
= List.Dates(#date(2025,1,1),365, #duration(1,0,0,0))
This will generate a list of all the dates in 2025.
Now, convert the list to a table using the List Tools > Transform ribbon.
Once you have the dates in a table format, you can use the “add column” ribbon and “Date” options to introduce many date related columns.
For example you can add:
- Year (4 digit year value)
- Month number
- Month name
- Weekday name
- Weekday number
- Start of month
- End of month
- Start of week
- Quarter of the year
- Days in a month
Additional "smart" date columns
Apart from all the columns above, I normally add these two columns to my calendar tables.
- Year month (a 6 digit representation like 202308 for ex.)
- Type of month (current month, previous month, next month)
Let’s look at the Power Query (M) code for these columns.
Year Month (yyyymm):
= Table.AddColumn(#"Inserted Start of Month", "Year Month", each [Year] * 100 + [Month])
Type of Month:
= Table.AddColumn(#"Added Custom", "Month Type", each if Date.IsInCurrentMonth([Date]) then "This Month"
else if Date.IsInPreviousMonth([Date]) then "Previous Month"
else if Date.IsInNextMonth([Date]) then "Next Month"
else "Other Month")
Full M Script for generating the 2025 calendar table
Use this M script to generate the calendar table for year 2025.
To apply this, create a blank query in PQ and then go to View > Advanced Editor and paste the code there. Adjust the year in source step (step 1) to get the calendar for any year.
let
Source = List.Dates(#date(2025,1,1),365, #duration(1,0,0,0)),
#"Converted to Table" = Table.FromList(Source, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
#"Renamed Columns" = Table.RenameColumns(#"Converted to Table",{{"Column1", "Date"}}),
#"Changed Type" = Table.TransformColumnTypes(#"Renamed Columns",{{"Date", type date}}),
#"Inserted Year" = Table.AddColumn(#"Changed Type", "Year", each Date.Year([Date]), Int64.Type),
#"Inserted Month" = Table.AddColumn(#"Inserted Year", "Month", each Date.Month([Date]), Int64.Type),
#"Inserted Month Name" = Table.AddColumn(#"Inserted Month", "Month Name", each Date.MonthName([Date]), type text),
#"Inserted Day of Week" = Table.AddColumn(#"Inserted Month Name", "Day of Week", each Date.DayOfWeek([Date]), Int64.Type),
#"Inserted Day Name" = Table.AddColumn(#"Inserted Day of Week", "Day Name", each Date.DayOfWeekName([Date]), type text),
#"Added Conditional Column" = Table.AddColumn(#"Inserted Day Name", "Is Weekend?", each if [Day of Week] = 6 then "Yes" else if [Day of Week] = 0 then "Yes" else "No"),
#"Inserted Start of Month" = Table.AddColumn(#"Added Conditional Column", "Start of Month", each Date.StartOfMonth([Date]), type date),
#"Added Custom" = Table.AddColumn(#"Inserted Start of Month", "Year Month", each [Year] * 100 + [Month]),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "Month Type", each if Date.IsInCurrentMonth([Date]) then "This Month"
else if Date.IsInPreviousMonth([Date]) then "Previous Month"
else if Date.IsInNextMonth([Date]) then "Next Month"
else "Other Month")
in
#"Added Custom1"
Perfect Calendar with Power Query - Video
Check out this video to understand the process better.
How to customize the Calendar Query for other years?
You can change the “Source” step and replace the year number or number of days to generate the calendar for whatever year you need. For example, to make the 2 years calendar for years 2026 and 2027, use this code:
= List.Dates(#date(2026,1,1),730, #duration(1,0,0,0))
To make the calendar for next “n” years:
We can use additional date functions in Power Query M language to generate the calendar for next “n” years from a start date. For example, if you change the source step to below code, you will get next 5 years calendar from 1-Jan-2025.
= let start_date = #date(2025,1,1), number_of_years = 5, end_date = Date.AddYears(start_date,number_of_years), total_days = Duration.Days(end_date - start_date)
in List.Dates(start_date,total_days, #duration(1,0,0,0))
More ways to make the calendar table
Check out below tutorials from other Power BI / Excel folks to see different Power Query scripts.













21 Responses to “How to Filter Odd or Even Rows only? [Quick Tips]”
Infact, instead of using =ISEVEN(B3), how about to use =ISEVEN(ROW())
So it takes away any chance of wrong referencing.
I like Daily Dose of Excel
I like it.
Just a heads up, you do need to have the Analysis ToolPak add-in activated to use the ISEVEN / ISODD functions. An alternative to ISEVEN would be:
=MOD(ROW(),2)=0
rather than use a formula, couldn't you enter "true" in first cell and "false" in the second and drag it down and than filter on true or false.
Just for clarification, is Ashish looking to filter by even or odd Characters or rows?
so many functions to learn!
Nice support by chandoo and team as a helpdesk. Give us more to learn and make us awesome. Always be helpful.......
In case you want to delete instead of filter,
IF your data is in Sheet1 column A
Put this in Sheet2 column A and drag down
=OFFSET(Sheet1!A$1,(ROWS($1:1)-1)*2,,)
(This is to delete even rows)
To delete odd rows :
=OFFSET(Sheet1!A$2,(ROWS($1:1)-1)*2,,)
If your numbered cells did not correspond to rows, the answer would be even simpler:
=MOD([cell address],2), then filter by 0 to see evens or 1 to see odds.
I sometimes do this using an even simpler method. I add a new column called "Sign" and put the value of 1 in the first row, say cell C2 if C1 contains the header. Then in C3 I put the formula =-1 * C2, which I copy and paste into the rest of the rows (so C4 has =-1 * C3 and so forth). Now I can just apply a filter and pick either +1 or -1 to see half the rows.
Another way, which works if I want three possibilities: in C2 I put the value 1, in C3 I put the value 2, in C4 I put the value 3, then in C5 I put the formula =C2 then I copy C5 and paste into all the remaining rows (so C6 gets =C3, C7 gets =C4, etc.). Now I can apply a filter and pick the value 1, 2, or 3 to see a third of the rows.
Extending this approach to more than 3 cases is left as an exercise for the reader.
Another way =MOD(ROW();2). In this case, must to choose betwen 1 and 0.
[...] How to Filter Even or Odd rows only [...]
very different style Odd or Even Rows very easy way to visit this site
http://www.handycss.com/tips/odd-or-even-rows/
Thanks for the tip, it worked like magic, saved having to delete row by row in my database.
Thanks!
Thankssssssssssssssss
Hi Chandoo- First of all thanks for the trick. It helped me a lot. Here I have one more challenge. Having filtered the data based on odd. I want to paste data in another sheet adjacent to it. How can I do that?
For Example-
A 1 odd
B 3 odd
C 4 even
D 6 even
I have fileted the above data for odd and want to copy the "This is odd number" text in adjacent/next sheet here. How can I do that. After doing this my data should look like this
A 1 odd This is odd number
B 3 odd This is odd number
C 4 even
D 6 even
Hi! Could you please help me find a formula to filter by language?
Thank you!
Chandoo SIR,
I HAVE A DATA IN EXCEL ROWS LIKE BELOW IS THERE ANY FORMULA OR A WAY WHERE I CAN INSTRUCT I CAN MAKE CHANGES , MEANS I WANT TO WRITE ONLY , THE FIG IS FRESH, BUT IN BELOW ROW IT WILL AUTOMATICALLY TAKE THE SOME WORDS FROM FIGS AND MAKE IN PLURAL FORM , WHILE USING '' ARE'' LIKE BELOW
The fig is fresh - row 1
Figs are fresh - row 2
The Pomegranate is red - row 3
Pomegranates are red - row 4
=IF(EVEN(A1)=A1,"EVEN - do something","ODD - do something else") with iferron (for blank Cell)