Creating Custom Calendars in Power BI

Mar 08, 2024

Introduction

Have you ever tried to add holidays which lie between today (or any dates) to a specific date or the same kind of scenario?

If yeah Then this article helps you

 

Scenario

Recently, I faced a situation where I needed to add days to the current date (today) which depends on the total number of hours left for a particular employee.

Means employee A has 150 hours left and spent only 6-hour for one working day, then divide the hour by daily spend and find the date (forecast date) where employee A completed their task but did not include holidays and weekends.

Let’s consider employee X. Get 15 fore-cast days on the basis of the hours left. Those 15 days do not include weekends and holidays, which we need to add to the current date (today). Let’s consider Employee X got 3 days of weekend or public holiday out of 15 days, then it also needs to add in fore-cast days, which means now 15 days become 18 days.  If employee X's forecast date falls on a weekend or a holiday, it is also not applicable.

 

We take some data for solving scenario

 

Holiday Table

 

Logic behind solving this problem is we going to take a separate date table which will help for deriving fore-cast date and add new column of Holidays. After that we add a new column which give us a flag of 0 if Date in weekends or in holidays and 1 for date in working day after that we give rank according to flag with exclude of Flag 0.

 


We make a new date Table which particular Use for Fore-cast Date Using Below DAX Code

Here I am taking only 2024 Date field

fore-cast Datetable = 
ADDCOLUMNS(
    CALENDAR(
        TODAY(),
        DATE(2024,12,31)
    ),
    "weekday",
    WEEKDAY([Date],2),
    "Dayname",
    FORMAT([Date],"dddd")
)

 

Join holiday Table and fore-cast Date table using Date field

 

 

Make a new column (Holiday) in Fore-cast Date table which help us to bring only holiday date from holiday table to existing table

holiday = RELATED('Holiday Table'[holiday date])

 

Make another new column with some condition using Dax code which give Flag 0 for those date which are weekends and holidays and 1 for Working days.

workingday = 
IF(
    NOT('fore-cast Datetable'[weekday]) in {6,7},
    IF(
        'fore-cast Datetable'[holiday]<>BLANK(),
        0,
        1
    ),
    0
)

Add column Which Give day no from Today with ignoring Weekends and holidays

Day Number = 
RANKX(
    FILTER(
        ALL('fore-cast Datetable'[Date],'fore-cast Datetable'[workingday]),
        'fore-cast Datetable'[workingday]<>0
    ),
    'fore-cast Datetable'[Date],,ASC
)

 

Our main goal is taking Days on behalf of Hours and find those date which is equivalent to left days from today with ignoring weekends and holidays. Day Number column give us that ability

 

Fore-cast date table Look like below

Now make a new column in employee table

Forecast date column = 
var a =FLOOR((Employee[Hour left]/6),1)
return
MAXX(
    FILTER(
        ALL('fore-cast Datetable'[Date],'fore-cast Datetable'[Day Number]),
        'fore-cast Datetable'[Day Number]=a
    ),
    'fore-cast Datetable'[Date]
)

 

We can make measure with little bit changes

fore-cast date using measure = 
var a = FLOOR(SUM(employee[hour left])/6,1)
return
MAXX(
    FILTER(
        ALL('fore-cast Datetable'[Date],'fore-cast Datetable'[Day Number]),
        'fore-cast Datetable'[Day Number]=a
    ),
    'fore-cast Datetable'[Date]
)

 

Make a table visual

 

 

If you don’t want to add new table to your Existing data model

We can also achieve Without fore-cast date table by creating it on fly.

 


Use below Dax code for column

fore-cast date without table refrence = 
var a = FLOOR(('Employee'[Hour left]/6),1)
var b =NETWORKDAYS(TODAY(),TODAY()+a,1)
var c = ADDCOLUMNS(
             CALENDAR(TODAY(),TODAY()+a+b),
             "weekday",
             WEEKDAY([Date],2),
             "dayname",FORMAT([Date],"dddd"),
             "publikholiday",LOOKUPVALUE('Holiday Table'[Holiday Date],[holiday date],[Date]),
             "holidaycondition",
                     var a1 = IF(
                                 not(WEEKDAY([Date],2)) in {6,7},
                                 IF(
                                       LOOKUPVALUE('Holiday Table'[Holiday Date],[holiday date],[Date])<>BLANK(),
                                       0,
                                       1
                                 ),
                                 0
                              )
              RETURN
              a1
        )
var f = ADDCOLUMNS(c,"rank",RANKX(FILTER(c,[holidaycondition]<>0),[Date],,ASC))
var e= MINX(FILTER(f,[rank]=a),[Date])
return
e

here little bit changes in above code for measure


Use below code for measure

fore-cast date measurewithout table refrence = 
var a = FLOOR(sum(employee[hour left])/6,1)
var b =NETWORKDAYS(TODAY(),TODAY()+a,1)
var c =ADDCOLUMNS(
          CALENDAR(TODAY(),TODAY()+a+b),
              "weekday",WEEKDAY([Date],2),
              "dayname",FORMAT([Date],"dddd"),
              "publikholiday",LOOKUPVALUE('Holiday Table'[Holiday Date],'Holiday Table'[holiday date],[Date]),
              "holidaycondition",
                  var a1 = IF(
                                not(WEEKDAY([Date],2)) in {6,7},
                                IF(
                                    LOOKUPVALUE('Holiday Table'[Holiday Date],'Holiday Table'[holiday date],[Date])<>BLANK(),
                                     0,
                                     1
                                ),
                                0
                            )
                  RETURN
                  a1
                )
var f = ADDCOLUMNS(c,"rank",RANKX(FILTER(c,[holidaycondition]<>0),[Date],,ASC))
var e= MINX(FILTER(f,[rank]=a),[Date])
return
e

 

Output without Using Table refrence

TAGS PowerBI DAX
Power BI: Connect & Normalize JSON Files
Mar 12, 2024

Introduction: Welcome to our guide on normalizing JSON files using Power Query! JSON (JavaScript Object Notation) has become one of the most popular formats for storing and exchanging data due to its simplicity and flexibility. However, working with JSON data in its raw form can sometimes be challenging, especially when dealing with nested structures or arrays. In this blog post, we'll delve into the process of normalizing JSON files using Power Query. Normalization refers to the process of organizing data into a tabular format, making it easier to analyze and manipulate.    First we need to import data in power bi desktop with Json connection.  click on get data inside home tab of power BI Desktop.   Click on more tab to get Json file connection. click on connect button which redirect you to your systeam then choose your Json file.   You redirect to your Power Query Editor. Power Query editor interface like below. Here we can check Table.column ,Table.Rows are in form of list Not in form of row data that we want. Click on one of list which show what inside of list. Here data inside of one  list.   It has around 121 rows inside one list and we need to expand it Row wise. so first idea is to exoand list column by left click on right side of column and choose expand new rows for every column which contains list.   But you notice that for one row there are multiple sub-rows which is not appropriate like below. Here for extract time(First row) only one row valid other rows are not valid or duplicate so these happen with every rows and roes count for table is not acceptable. so our approach is not valid here we miss something In above image(image 5) table.rows and table.column has list in row. if you turn by turn expand both list you notice that both list has data(in some case same rows and in other case rows are not same) with same row count which indicate that both lists data are connected with each other. so we need to make a new column which combine both list in form of table . Go to add column tab> select custome column  it open  custome column interface and write code like below. Table.FromColumns({[Tables.Columns],[Tables.Rows]})  it add new column in existing table like below. when you click on customecolumns row you will redirect to expanded version of table which look like below.   now we can normalize data. now we can separate table to multiple table by for easy for data modeling  create duplicate table and filter out as needed  now close your power query tab and you get your desired output below is advance editor code if you don't want to apply all  steps that we implemented above let Source = Json.Document(File.Contents("C:\Users\MagnusMinds\Downloads\Order_CRHESTHASH_ET_FD2024-03-11_PID184_ORD686_MRK2024-03-08 09 14 44.410_T00638455040948575166.json")), #"Converted to Table" = Table.FromRecords({Source}), #"Expanded Tables" = Table.ExpandListColumn(#"Converted to Table", "Tables"), #"Expanded Tables1" = Table.ExpandRecordColumn(#"Expanded Tables", "Tables", {"Name", "QueryStartTimeUtc", "QueryEndTimeUtc", "QueryElapsedTimeMs", "CurrentRow", "Columns", "Rows", "OriginalRowCount", "Hashes", "MasterRecordIsDuplicate"}, {"Tables.Name", "Tables.QueryStartTimeUtc", "Tables.QueryEndTimeUtc", "Tables.QueryElapsedTimeMs", "Tables.CurrentRow", "Tables.Columns", "Tables.Rows", "Tables.OriginalRowCount", "Tables.Hashes", "Tables.MasterRecordIsDuplicate"}), #"Changed Type" = Table.TransformColumnTypes(#"Expanded Tables1",{{"Tables.Name", type text}, {"Tables.QueryStartTimeUtc", type datetime}, {"Tables.QueryEndTimeUtc", type datetime}, {"Tables.QueryElapsedTimeMs", Int64.Type}, {"Tables.CurrentRow", Int64.Type}, {"Tables.Columns", type any}, {"Tables.Rows", type any}, {"Tables.OriginalRowCount", Int64.Type}, {"Tables.Hashes", type any}, {"Tables.MasterRecordIsDuplicate", type logical}}), #"Expanded Tables.Rows" = Table.ExpandListColumn(#"Changed Type", "Tables.Rows"), #"Added Custom" = Table.AddColumn(#"Expanded Tables.Rows", "Customcolumn", each Table.FromColumns({[Tables.Columns],[Tables.Rows]})), #"Expanded Customcolumn" = Table.ExpandTableColumn(#"Added Custom", "Customcolumn", {"Column1", "Column2"}, {"Customcolumn.Column1", "Customcolumn.Column2"}), #"Expanded Customcolumn.Column1" = Table.ExpandRecordColumn(#"Expanded Customcolumn", "Customcolumn.Column1", {"Name"}, {"Customcolumn.Column1.Name"}) in #"Expanded Customcolumn.Column1"  

Nirav Dangar

About the Author

Nirav Dangar