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

The Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.

Reply
BiscuitKen
Frequent Visitor

Conditionally Update Columns in Pivoted Data

Hi

 

I've pivoted data and now want to update the values that are null to STANDARD but only where 'WorkType' = SHIFT regardless of the dates in the column headers as these will change.

 

The data looks like this

 

Employee NumberWorkType20/05/202421/05/202422/05/202423/05/202424/05/2024
00001SHIFTnullnullSTANDARDSTANDARDSTANDARD
00002SHIFTnullnullSTANDARDSTANDARDSTANDARD
00003SHIFTSTANDARDSTANDARDSTANDARDSTANDARDSTANDARD
00004STANDBYnullnullnullnullnull
00005SHIFTSTANDARDSTANDARDSTANDARDnullSTANDARD
00006SHIFTSTANDARDSTANDARDSTANDARDSTANDARDSTANDARD
00007SHIFTSTANDARDSTANDARDSTANDARDSTANDARDSTANDARD
00008SHIFTnullnullSTANDARDSTANDARDSTANDARD
00009STANDBYnullnullnullnullnull
00010SHIFTSTANDARDSTANDARDSTANDARDSTANDARDSTANDARD

 

I've added this line to the query;

 

= Table.ReplaceValue(#"Pivoted Column",null,"STANDARD",Replacer.ReplaceValue,Table.ColumnNames(#"Pivoted Column"))

 

 

This replaces all null values but I only want to update the rows that are SHIFT and leave the STANDBY row as null.

 

Any help would be appreciated.

1 ACCEPTED SOLUTION
slorin
Super User
Super User

Hi @BiscuitKen 

 

 

= Table.ReplaceValue(#"Pivoted Column",null, each if [WorkType]="SHIFT" then "STANDARD" else null,Replacer.ReplaceValue,Table.ColumnNames(#"Pivoted Column"))

 Stéphane

View solution in original post

3 REPLIES 3
v-cgao-msft
Community Support
Community Support

Hi @BiscuitKen ,

How about replacing before pivot columns?

vcgaomsft_0-1716356712203.png

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("jZU7DoMwEETv4hop9hp/UhKhKGlSBJoIcf9rhCoKu4yZysJviqfRrlkWF1znpsfzPm+n+ItPF/HSbx9u7RQNTSp/dJqH1zi8R5uKVKpHKWnaStNWKFuhbIWyjcgWpwKVgvaRso+U/e/i9jlsW3HTt+JywuMJ7zVPVLuJajdR7SbUrqWw1UxZZ8o6U9YZWeMUtC+UfaHsC2VfKPtC2dfm61GRtaXQtlK2lbK9nuyf4sZYcbN/ipt5VtzsX/DUMOxjcBr2Mfwz8VTD+9hxxesX", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Employee Number" = _t, WorkType = _t, Attribute = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Employee Number", Int64.Type}}),
    #"Replaced Value" = Table.ReplaceValue(#"Changed Type","",each if [WorkType] = "SHIFT" then "STANDARD" else null,Replacer.ReplaceValue,{"Value"}),
    #"Pivoted Column" = Table.Pivot(#"Replaced Value", List.Distinct(#"Replaced Value"[Attribute]), "Attribute", "Value")
in
    #"Pivoted Column"

vcgaomsft_1-1716356778503.png

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly --  How to provide sample data in the Power BI Forum -- China Power BI User Group

Hi @v-cgao-msft 

Thank you for your solution but I'm afraid it's not suitable for my senario.  There are no null values to update prior to the pivot.  The null values appear after the pivot as a row may not contain a value for all columns whereas other row my contain a value.

slorin
Super User
Super User

Hi @BiscuitKen 

 

 

= Table.ReplaceValue(#"Pivoted Column",null, each if [WorkType]="SHIFT" then "STANDARD" else null,Replacer.ReplaceValue,Table.ColumnNames(#"Pivoted Column"))

 Stéphane

Helpful resources

Announcements
Feb2025 Sticker Challenge

Join our Community Sticker Challenge 2025

If you love stickers, then you will definitely want to check out our Community Sticker Challenge!

Jan NL Carousel

Fabric Community Update - January 2025

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

Top Solution Authors
Top Kudoed Authors