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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
Maxgurung
Frequent Visitor

PowerBI struggling to fill empty cell in column based on start date and end date conditions

I am new to powerBI and struggling to copy data in powerbi table. I am tring to add column where if well_name is as said in well_name column and the start date and end date is as said in start date and end date column then fill the esp_id between those date. eg. for R-010 wellname, i want the esp_id to be filled in as 357106 between recorded_date 28/july/2018 to 06/August/2021 and like wise for R-001, esp_id 354504 to be filled in dates between 23/feb/2017 to 19/may/2018. is this possible?

See screen shot for more clarity.

Maxgurung_0-1632745347163.png

 

Many thanks

1 ACCEPTED SOLUTION

Hi @Maxgurung 

I think you can try to transform your table in Power Query Editor.

Here is my M code.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("hdLLCcMwEIThVozOFuyOokfayNW4/zaiOLl4R2TAF/EhY37PcaRXNre0J5iPbD1fh99z7gt34RBehD+EV+FNeBc+hD//O0Q/iH4Q/SD6QfSD6AfRD6IfBh/g2eb58+ZSu1vb1ldF2iLSFkpbr7XMD7C528V0g1P64JQ+OKUPTumDt3j4Bqulb+sL9C+C05aDU/C785aDi6C85eAi6G3L5xs=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [wellbore_ID = _t, RECORDED_DATE = _t, start_date = _t, end_date = _t, esp_id = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"wellbore_ID", type text}, {"RECORDED_DATE", type date}, {"start_date", type date}, {"end_date", type date}, {"esp_id", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"wellbore_ID"}, {{"Rows", each _, type table [wellbore_ID=nullable text, RECORDED_DATE=nullable date, start_date=nullable date, end_date=nullable date, esp_id=nullable number]}}),
    #"Duplicated Column" = Table.DuplicateColumn(#"Grouped Rows", "Rows", "Rows - Copy"),
    #"Expanded Rows - Copy" = Table.ExpandTableColumn(#"Duplicated Column", "Rows - Copy", {"start_date", "end_date", "esp_id"}, {"Rows - Copy.start_date", "Rows - Copy.end_date", "Rows - Copy.esp_id"}),
    #"Filtered Rows" = Table.SelectRows(#"Expanded Rows - Copy", each ([#"Rows - Copy.start_date"] <> null)),
    #"Expanded Rows" = Table.ExpandTableColumn(#"Filtered Rows", "Rows", {"RECORDED_DATE", "start_date", "end_date", "esp_id"}, {"Rows.RECORDED_DATE", "Rows.start_date", "Rows.end_date", "Rows.esp_id"}),
    #"Renamed Columns" = Table.RenameColumns(#"Expanded Rows",{{"Rows.RECORDED_DATE", "RECORDED_DATE"}, {"Rows - Copy.start_date", "start_date"}, {"Rows - Copy.end_date", "end_date"}, {"Rows - Copy.esp_id", "Test_esp_id"}}),
    #"Added Custom" = Table.AddColumn(#"Renamed Columns", "Result", each if [RECORDED_DATE]>=[start_date] then if [end_date] = null then [Test_esp_id] else if [RECORDED_DATE]<=[end_date] then
[Test_esp_id] else null else null),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Test_esp_id", "start_date", "end_date"}),
    #"Renamed Columns1" = Table.RenameColumns(#"Removed Columns",{{"Rows.esp_id", "esp_id"}, {"Rows.end_date", "end_date"}, {"Rows.start_date", "start_date"}})
in
    #"Renamed Columns1"

Result is a below.

1.png

Best Regards,
Rico Zhou

 

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

3 REPLIES 3
amitchandak
Super User
Super User

@Maxgurung , Try a new column , change columns as per need 

 

Switch( True(),
[Wellname] ="R-010" && [Recorded Date] >= Date(2018,07, 28) && [Recorded Date] <= Date(2018,08, 06), 357106 ,
[Wellname] ="R-001" && [Recorded Date] >= Date(2017,02, 17) && [Recorded Date] <= Date(2018,05, 19), 354504
)

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here

Hi Amit,

Thanks for quick response. However, the job is more complicated then mentioned. I have 100s of well name so i wanted it to be able to detect the well name itself (a bit like vlookup in excel) as if not i will be typing it manually. also i have 100s of esp_id and i want the query to identify esp_id for that well name at that date. eg. for well R-010, the esp id is listed once with start date on 28/july/2018. that means for all the entry with R-010 well name, from 28/july/2018, i wanted the esp_id listed at start date of 28/july/2018 to fill in the column. Hope this makes sense.

Thank you for help!

Max

Hi @Maxgurung 

I think you can try to transform your table in Power Query Editor.

Here is my M code.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("hdLLCcMwEIThVozOFuyOokfayNW4/zaiOLl4R2TAF/EhY37PcaRXNre0J5iPbD1fh99z7gt34RBehD+EV+FNeBc+hD//O0Q/iH4Q/SD6QfSD6AfRD6IfBh/g2eb58+ZSu1vb1ldF2iLSFkpbr7XMD7C528V0g1P64JQ+OKUPTumDt3j4Bqulb+sL9C+C05aDU/C785aDi6C85eAi6G3L5xs=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [wellbore_ID = _t, RECORDED_DATE = _t, start_date = _t, end_date = _t, esp_id = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"wellbore_ID", type text}, {"RECORDED_DATE", type date}, {"start_date", type date}, {"end_date", type date}, {"esp_id", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"wellbore_ID"}, {{"Rows", each _, type table [wellbore_ID=nullable text, RECORDED_DATE=nullable date, start_date=nullable date, end_date=nullable date, esp_id=nullable number]}}),
    #"Duplicated Column" = Table.DuplicateColumn(#"Grouped Rows", "Rows", "Rows - Copy"),
    #"Expanded Rows - Copy" = Table.ExpandTableColumn(#"Duplicated Column", "Rows - Copy", {"start_date", "end_date", "esp_id"}, {"Rows - Copy.start_date", "Rows - Copy.end_date", "Rows - Copy.esp_id"}),
    #"Filtered Rows" = Table.SelectRows(#"Expanded Rows - Copy", each ([#"Rows - Copy.start_date"] <> null)),
    #"Expanded Rows" = Table.ExpandTableColumn(#"Filtered Rows", "Rows", {"RECORDED_DATE", "start_date", "end_date", "esp_id"}, {"Rows.RECORDED_DATE", "Rows.start_date", "Rows.end_date", "Rows.esp_id"}),
    #"Renamed Columns" = Table.RenameColumns(#"Expanded Rows",{{"Rows.RECORDED_DATE", "RECORDED_DATE"}, {"Rows - Copy.start_date", "start_date"}, {"Rows - Copy.end_date", "end_date"}, {"Rows - Copy.esp_id", "Test_esp_id"}}),
    #"Added Custom" = Table.AddColumn(#"Renamed Columns", "Result", each if [RECORDED_DATE]>=[start_date] then if [end_date] = null then [Test_esp_id] else if [RECORDED_DATE]<=[end_date] then
[Test_esp_id] else null else null),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Test_esp_id", "start_date", "end_date"}),
    #"Renamed Columns1" = Table.RenameColumns(#"Removed Columns",{{"Rows.esp_id", "esp_id"}, {"Rows.end_date", "end_date"}, {"Rows.start_date", "start_date"}})
in
    #"Renamed Columns1"

Result is a below.

1.png

Best Regards,
Rico Zhou

 

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

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

Check out the November 2024 Power BI update to learn about new features.