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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Yester07
Frequent Visitor

Insert a new row if 2 fields are field

Hello,

 

I have a complex question I tried many solutions (please see below). I want to check if 2 fields are filled (not empty), if it is the case, I want to create a new row :

         1. In the first one (the original one), Keep the value of column B and delete the value of column C

         2. Adding a new row and keeping the value of column C and empty in the column B

Table : 

Col ACol B Col CCol D
A1 C1D1
A2BXC2D2
A3BZC3D3
A4B4 D4

 

Results : 

Col ACol B Col CCol D
A1 C1D1
A2BX D2
A2 C2D2
A3BZ D3
A3 C3D3
A4B4 D4

 

I tried adding a new column where I check if 2 values are not empty, then I put the value of the column C. The probleme is the merging is not working and it can not enable me to delete the value of the row B in the orignial row :

= Table.AddColumn(#"Added Custom", "Custom", each if ([B] <> null and [C] <> null) then (Table.InsertRows(#"Added Custom", 0, {[A=[A], code fab B=[B], C="",D=[D]]}))else null)

When I expand columns, I have the first value of B and C in all the columns B and C...

= Table.ExpandTableColumn(#"Added Conditional Column", "Custom", {"A", "B", "C", "D"}, {"Custom.A", "Custom.B", "Custom.C", "Custom.d"})

 

I also tried to duplicate the rows where B and C are not empty, but I can not make a deletion at the same time...

1 ACCEPTED SOLUTION

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcjRU0lECImcQ7WKoFKsDFDMCsp0iQKIglosRRNQYJBoFEgWxXIwhoiYgUROIIS4mSrGxAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Col A" = _t, #"Col B" = _t, #"Col C" = _t, #"Col D" = _t]),
    #"Added Custom" = Table.AddColumn(Source, "Custom", each if ([Col B]<>"" and [Col B]<>null) and ([Col C]<>"" and [Col C]<>null) then {1,2} else null),
    #"Expanded Custom" = Table.ExpandListColumn(#"Added Custom", "Custom"),
    Custom1 = Table.ReplaceValue(#"Expanded Custom",each [Col C],each if [Custom] = 1 then null else [Col C],Replacer.ReplaceValue,{"Col C"}),
    Custom2 = Table.ReplaceValue(#"Custom1",each [Col B],each if [Custom] = 2 then null else [Col B],Replacer.ReplaceValue,{"Col B"}),
    #"Removed Columns" = Table.RemoveColumns(Custom2,{"Custom"})
in
    #"Removed Columns"

View solution in original post

4 REPLIES 4
Vijay_A_Verma
Super User
Super User

I need to know the logic for treatment of last row where B4 is present but C4 is not present. But your output shows a single row which removes B4 and brings in C4 whereas C4 was nor present in your input table.

Sorry, it is just an input error. If only B or only C is filled, no treatment is done. thank you.

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcjRU0lECImcQ7WKoFKsDFDMCsp0iQKIglosRRNQYJBoFEgWxXIwhoiYgUROIIS4mSrGxAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Col A" = _t, #"Col B" = _t, #"Col C" = _t, #"Col D" = _t]),
    #"Added Custom" = Table.AddColumn(Source, "Custom", each if ([Col B]<>"" and [Col B]<>null) and ([Col C]<>"" and [Col C]<>null) then {1,2} else null),
    #"Expanded Custom" = Table.ExpandListColumn(#"Added Custom", "Custom"),
    Custom1 = Table.ReplaceValue(#"Expanded Custom",each [Col C],each if [Custom] = 1 then null else [Col C],Replacer.ReplaceValue,{"Col C"}),
    Custom2 = Table.ReplaceValue(#"Custom1",each [Col B],each if [Custom] = 2 then null else [Col B],Replacer.ReplaceValue,{"Col B"}),
    #"Removed Columns" = Table.RemoveColumns(Custom2,{"Custom"})
in
    #"Removed Columns"

Okey, you create a list of 1 and 2 for each row where the value of B and C are not null/empty. Thank you so much! 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors
Top Kudoed Authors