excel transpose text

kfhw720

New Member
Joined
May 3, 2024
Messages
10
Office Version
  1. 365
Platform
  1. Windows
Hi, I have a spreadsheet which has 5 columns. I want it transposed by project, listing all the names of people working on that project in columns. On top of that I want anyone with an 'L' in column E to be highlighted in green (but only for the associated project) and same for anyone with an 'O' highlighted in blue. Can anyone help?
 

Attachments

  • ex-raw.jpg
    ex-raw.jpg
    104.8 KB · Views: 9
  • ex-res.jpg
    ex-res.jpg
    27 KB · Views: 9

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
Hello, please test this:

a) transposed table:

Excel Formula:
=LET(
projects,B2:B36,
names,A2:A36,
u,UNIQUE(projects),
n,IFNA(DROP(REDUCE("",u,LAMBDA(a,b,VSTACK(a,TRANSPOSE(UNIQUE(FILTER(names,projects=b)))))),1),""),
HSTACK(u,n))

b) conditional formatting (adjust the first part of XLOOKUP based on your transposed table):

Excel Formula:
=XLOOKUP($F2&G2,$B$2:$B$36&$A$2:$A$36,$E$2:$E$36,"")="O"

Excel Formula:
=XLOOKUP($F2&G2,$B$2:$B$36&$A$2:$A$36,$E$2:$E$36,"")="L"
 
Upvote 0
Thank you! :)
The first part works well, but for the formatting, which cell do I put the formula into? I don't really get that bit.
 
Upvote 0
Thank you! :)
The first part works well, but for the formatting, which cell do I put the formula into? I don't really get that bit.

Highlight all the names in the new table and then go to conditional formatting and insert the formula (just adjust the first part of the formula, i.e. $F2&G2 base on the actual range of your transposed table where $F2 is the first project and G2 is the first name belonging to the first project).
 
Upvote 0
Sorry, one more thing. Do you know if there is anyway to keep formatting in the transpose? I.E. If I highlighted the names first before transposing the table.
And also if there is a way to ignore certain values of PROJECT? e.g. If PROJECT contains '[TBD]' then do not include in table.
 
Upvote 0
As far as formatting is concerned, you can always copy and paste the format you need; as for the latter question, it is of course possible but what are the values you would like to exclude and how would you like to do it (to have a list of projects, drop-down menu...)?
 
Upvote 0
I want it to list all projects in the result table, excluding any project which contains the text 'TBD'. Thank you!
 
Upvote 0
Would this do the trick?

Excel Formula:
=LET(
projects,B2:B36,
names,A2:A36,
u,UNIQUE(FILTER(projects,ISNUMBER(FIND("TBD",projects))=FALSE)),
n,IFNA(DROP(REDUCE("",u,LAMBDA(a,b,VSTACK(a,TRANSPOSE(UNIQUE(FILTER(names,projects=b)))))),1),""),
HSTACK(u,n))

P. S. Please note that "FIND" is case sensitive, i.e. if it might happen that there will be some inconsistency (e.g. TbD), replace it with SEARCH.
 
Upvote 0

Forum statistics

Threads
1,223,911
Messages
6,175,331
Members
452,636
Latest member
laura12345

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