The ultimate Fabric, Power BI, SQL, and AI community-led learning event. Save €200 with code FABCOMM.
Get registeredEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
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 Number | WorkType | 20/05/2024 | 21/05/2024 | 22/05/2024 | 23/05/2024 | 24/05/2024 |
00001 | SHIFT | null | null | STANDARD | STANDARD | STANDARD |
00002 | SHIFT | null | null | STANDARD | STANDARD | STANDARD |
00003 | SHIFT | STANDARD | STANDARD | STANDARD | STANDARD | STANDARD |
00004 | STANDBY | null | null | null | null | null |
00005 | SHIFT | STANDARD | STANDARD | STANDARD | null | STANDARD |
00006 | SHIFT | STANDARD | STANDARD | STANDARD | STANDARD | STANDARD |
00007 | SHIFT | STANDARD | STANDARD | STANDARD | STANDARD | STANDARD |
00008 | SHIFT | null | null | STANDARD | STANDARD | STANDARD |
00009 | STANDBY | null | null | null | null | null |
00010 | SHIFT | STANDARD | STANDARD | STANDARD | STANDARD | STANDARD |
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.
Solved! Go to Solution.
Hi @BiscuitKen
= Table.ReplaceValue(#"Pivoted Column",null, each if [WorkType]="SHIFT" then "STANDARD" else null,Replacer.ReplaceValue,Table.ColumnNames(#"Pivoted Column"))
Stéphane
Hi @BiscuitKen ,
How about replacing before pivot columns?
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"
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 @Anonymous
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.
Hi @BiscuitKen
= Table.ReplaceValue(#"Pivoted Column",null, each if [WorkType]="SHIFT" then "STANDARD" else null,Replacer.ReplaceValue,Table.ColumnNames(#"Pivoted Column"))
Stéphane