+ Reply to Thread
Results 1 to 8 of 8

Transpose Formula

  1. #1
    Registered User
    Join Date
    06-05-2017
    Location
    US
    MS-Off Ver
    2013
    Posts
    33

    Transpose Formula

    Hey All,

    I'm looking for a formula that can both transpose and filter, so there's no repeats, one column of data (B4:B38) to the row (B74:Z74). Also I'm in need of another formula that can transfer the data from column (C4:C38) to column (B75:B81) if the data applies, if no then I'd like for it to display a 0. I tried using the transpose command but I cant get it to work. Any help would be much appreciated. Attached is an example of what I'm looking for.
    Attached Files Attached Files

  2. #2
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,137

    Re: Transpose Formula

    A68 should read jason.


    1. An array formula in B74:
    =IFERROR(INDEX($B$4:$B$38,MATCH(0,IF($B$4:$B$38<>"",COUNTIF($A$74:A74,$B$4:$B$38)),0)),"")



    2. Kill the merged cells, and it's easy: in B75, copied across and down:

    =SUMIFS($C$4:$C$38,$A$4:$A$38,$A75,$B$4:$B$38,B$74)

    Array Formulae are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.

    You will know the array is active when you see curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - appear around the outside of your formula. If you do not use CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly brackets yourself - it won't work...
    Attached Files Attached Files
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU

  3. #3
    Registered User
    Join Date
    06-05-2017
    Location
    US
    MS-Off Ver
    2013
    Posts
    33

    Re: Transpose Formula

    Thank you! This worked perfectly!

  4. #4
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,137

    Re: Transpose Formula

    You're welcome!!

  5. #5
    Registered User
    Join Date
    06-05-2017
    Location
    US
    MS-Off Ver
    2013
    Posts
    33

    Re: Transpose Formula

    Hey I've got one more question. If I were to move that bottom section that you typed the code for to another sheet (meaning I would know have a sheet1 and sheet2) would changing the formula be as simple as typing Sheet1 in front?
    ex:
    =SHEET1(IFERROR(INDEX($B$4:$B$38,MATCH(0,IF($B$4:$B$38<>"",COUNTIF($A$74:A74,$B$4:$B$38)),0)),""))
    or how would I type it for that formula and the other?

  6. #6
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,137

    Re: Transpose Formula

    No...

    =IFERROR(INDEX('Sheet1'!$B$4:$B$38,MATCH(0,IF('Sheet1'!$B$4:$B$38<>"",COUNTIF($A$74:A74,'Sheet1'!$B$4:$B$38)),0)),"")

    should do it...

  7. #7
    Registered User
    Join Date
    06-05-2017
    Location
    US
    MS-Off Ver
    2013
    Posts
    33

    Re: Transpose Formula

    You sir are a lifesaver! Thank you again and have an amazing day!

  8. #8
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,137

    Re: Transpose Formula

    =IFERROR(INDEX('Sheet1'!$B$4:$B$38,MATCH(0,IF('Sheet1'!$B$4:$B$38<>"",COUNTIF($A$74:A74,'Sheet1'!$B$4:$B$38)),0)),"")

    I forgot to add that the bit in red should refer to the cell IMMEDIATELY TO THE LEFT of the first cell that you want to get the results in... Make sure that you get the $ signs right!!

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. transpose column to a range calculate and transpose to new table loop
    By moshro1 in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 01-02-2015, 10:52 AM
  2. [SOLVED] Transpose: How can I copy a list and transpose it but leaving 3 cells in between each item
    By cocolete in forum Excel Programming / VBA / Macros
    Replies: 7
    Last Post: 04-11-2012, 10:01 AM
  3. Replies: 2
    Last Post: 02-19-2007, 04:53 PM
  4. transpose formula
    By Mika in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 01-27-2006, 11:30 AM
  5. formula to transpose
    By oberon.black in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 10-25-2005, 08:05 PM
  6. Transpose formula
    By Biff in forum Excel Formulas & Functions
    Replies: 9
    Last Post: 09-06-2005, 04:05 AM

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1