Get and Transform - changing/finding value if blank

cmcreynolds

Active Member
Joined
May 21, 2015
Messages
295
Hello, I hope everyone is well. Long time, no post :)

I receive non-normalized data from our field staff who are in teams of 2. For our final analysis, we choose only the team lead (indicated in its own field/column as TL). However, on rare occasion, they leave their response blank and we need to consider the other team member's response.

The issue is there are 82 fields to consider (not my structure, btw). I could come up with an approach if there were only a handful of fields, but writing 82 IF statements would drive me quite bonkers.

I use Get and Transform to extract the data from various folders and I was hoping the solution could be used there. But I could only find a way to replace variables one column at a time.

Here's a short version of how the data is set up.

SiteCode
TeamLead
Q1
Q2
Q3
Q4
033
TL
1
2
3
5
033
NL
1
2
3
5
151
TL
99
2
4
4
151
NL
1
2
3
3
222
TL
4
99
1
1
222
NL
2
4
2
3
167
TL
99
0
99
99
167
NL
1
3
2
2

<tbody>
</tbody>


Basically, whenever a TL has a '99' we look at the NL's response. Example: For Q1, site 151, we would want a '1' in the final data set

Again, I have 82 fields to apply this to.

(I looked at 'Group By' and it seemed daunting, I was hoping there was functionality I was overlooking - either in PowerQuery or PowerPivot)

Thank you!
Clifton
 

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"
Assuming data is in range Table1 including headers, you probably want to do something like this

Click on first two columns, right click choose "unpivot other columns"
Add a custom column that does what you need to do on the number field
Remove the value field
Click on Attribute Column, do Transform...Pivot and for value column use the new custom column


Code:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(Source, {"SiteCode", "TeamLead"}, "Attribute", "Value"),
    #"Added Custom" = Table.AddColumn(#"Unpivoted Other Columns", "Custom", each [Value]+1),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Value"}),
    #"Pivoted Column" = Table.Pivot(#"Removed Columns", List.Distinct(#"Removed Columns"[Attribute]), "Attribute", "Custom", List.Sum)
in
    #"Pivoted Column"
 
Upvote 0
I think the complexity is the custom column - the formula to check for '99', then go to the other entry.

Assuming data is in range Table1 including headers, you probably want to do something like this

Click on first two columns, right click choose "unpivot other columns"
Add a custom column that does what you need to do on the number field
Remove the value field
Click on Attribute Column, do Transform...Pivot and for value column use the new custom column


Code:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(Source, {"SiteCode", "TeamLead"}, "Attribute", "Value"),
    #"Added Custom" = Table.AddColumn(#"Unpivoted Other Columns", "Custom", each [Value]+1),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Value"}),
    #"Pivoted Column" = Table.Pivot(#"Removed Columns", List.Distinct(#"Removed Columns"[Attribute]), "Attribute", "Custom", List.Sum)
in
    #"Pivoted Column"
 
Upvote 0
I'll use the table from above as an example of the resulting data set

SiteCodeTeamLead(redundant in final)Q1Q2Q3Q4
033TL1235
151TL1244
222TL4411
167TL1022

<tbody>
</tbody>

Basically, a grouping with condition, I think?
 
Last edited:
Upvote 0
maybe try

Code:
[SIZE=1]let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"SiteCode", type text}}),
    #"Filtered Rows1" = Table.SelectRows(#"Changed Type", each ([TeamLead] = "TL")),
    #"Added Index" = Table.AddIndexColumn(#"Filtered Rows1", "Index", 1, 1),
    #"Unpivoted Only Selected Columns" = Table.Unpivot(#"Added Index", {"Q1", "Q2", "Q3", "Q4"}, "Attribute", "Value"),
    #"Added Conditional Column" = Table.AddColumn(#"Unpivoted Only Selected Columns", "Custom", each if [Value] = 99 then [Value]-98 else [Value]),
    #"Removed Columns" = Table.RemoveColumns(#"Added Conditional Column",{"Value"}),
    #"Pivoted Column" = Table.Pivot(#"Removed Columns", List.Distinct(#"Removed Columns"[Attribute]), "Attribute", "Custom", List.Sum),
    #"Sorted Rows" = Table.Sort(#"Pivoted Column",{{"Index", Order.Ascending}}),
    #"Removed Columns1" = Table.RemoveColumns(#"Sorted Rows",{"Index"})
in
    #"Removed Columns1"[/SIZE]
 
Upvote 0
or just this

Code:
[SIZE=1]let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"SiteCode", type text}}),
    #"Replaced Value" = Table.ReplaceValue(#"Changed Type",99,1,Replacer.ReplaceValue,{"Q1", "Q2", "Q3", "Q4"}),
    #"Filtered Rows" = Table.SelectRows(#"Replaced Value", each ([TeamLead] = "TL"))
in
    #"Filtered Rows"[/SIZE]
 
Upvote 0
Thank you very much, however I'm doing more than just replacing '99' with '1', I'm trying to replace it with what the NL had.
 
Upvote 0
so is that what you want?

SiteCodeTeamLeadQ1Q2Q3Q4
033TL
1​
2​
3​
5​
033NL
1​
2​
3​
5​
151​
TL
99​
2​
4​
4​
151​
NL
1​
2​
3​
3​
222​
TL
4​
99​
1​
1​
222​
NL
2​
4​
2​
3​
167​
TL
99​
0​
99​
99​
167​
NL
1​
3​
2​
2​
SiteCodeTeamLeadQ1Q2Q3Q4
033TL
1​
2​
3​
5​
033NL
1​
2​
3​
5​
151​
TL
1​
2​
4​
4​
151​
NL
1​
2​
3​
3​
222​
TL
4​
4​
1​
1​
222​
NL
2​
4​
2​
3​
167​
TL
1​
0​
2​
2​
167​
NL
1​
3​
2​
2​

if yes I'll see what can I do
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,202
Members
448,554
Latest member
Gleisner2

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top