+ Reply to Thread
Results 1 to 16 of 16

Highlight cells, closest to zero and a specified number, and corresponding cells

  1. #1
    Registered User
    Join Date
    01-26-2019
    Location
    south carolina, usa
    MS-Off Ver
    2016
    Posts
    8

    Highlight cells, closest to zero and a specified number, and corresponding cells

    I need help with the following:

    1. Highlight the cell that contains the number closest to zero in the "-1.6" columns
    2. Highlight the cell that contains the number closest to 1.600 in the "+/-%" columns
    3. Highlight the cell that corresponds to the closest number to 1.600 in the "POST C276 +/-%" columns
    4. Apply to all rows

    image is attached to help visually bc this forum does not support tables


    help.JPG

    # SN TBD 10pF +8% -1.6 +6% -1.6 +4% -1.6 -5% -1.6 -9.2% -1.6 -13% -1.6 post c276 +8% post c276 +6% post c276 +4% post c276 -5% post c276 -9.2% post c276 -13%
    1 1234 75 1.84221 1.98959 0.3896 1.95274 0.3527 1.91590 0.3159 1.75010 0.1501 1.67273 0.0727 1.60272 0.00272
    2 1235 59 1.70000 1.83600 0.2360 1.80200 0.2020 1.76800 0.1680 1.61500 0.0150 1.54360 -0.0564 1.47900 -0.12100

  2. #2
    Forum Expert Pepe Le Mokko's Avatar
    Join Date
    05-14-2009
    Location
    Belgium
    MS-Off Ver
    O365 v 2402
    Posts
    13,453

    Re: Highlight cells, closest to zero and a specified number, and corresponding cells

    Attach a sample workbook (not a picture or pasted copy). Make sure there is just enough data to demonstrate your need. Include a BEFORE sheet and an AFTER sheet in the workbook if needed to show the process you're trying to complete or automate. Make sure your desired results are shown, mock them up manually if necessary.

    Remember to desensitize the data.

    Click on GO ADVANCED and then scroll down to Manage Attachments to open the upload window.

  3. #3
    Registered User
    Join Date
    01-26-2019
    Location
    south carolina, usa
    MS-Off Ver
    2016
    Posts
    8

    Re: Highlight cells, closest to zero and a specified number, and corresponding cells

    thanks for the advice, Pepe Le Mokko
    i'll update and upload in a bit

  4. #4
    Registered User
    Join Date
    01-26-2019
    Location
    south carolina, usa
    MS-Off Ver
    2016
    Posts
    8

    Post Re: Highlight cells, closest to zero and a specified number, and corresponding cells

    i updated and uploaded a workbook with before and after sheets
    Attached Files Attached Files

  5. #5
    Forum Expert
    Join Date
    10-15-2018
    Location
    MA, USA
    MS-Off Ver
    2010, 2019
    Posts
    1,616

    Re: Highlight cells, closest to zero and a specified number, and corresponding cells

    To compute the nearest values I needed an array formula.
    As conditional formatting can't use array formulas I need a helper row (row 13).
    In F13, H13, J13, L13, N13, P13, R13:W13
    Formula: copy to clipboard
    Please Login or Register  to view this content.

    In G13, I13, K13, M13, O13, Q13
    Formula: copy to clipboard
    Please Login or Register  to view this content.


    Apply the follwing conditional formatting to F2:W5
    Formula: copy to clipboard
    Please Login or Register  to view this content.

    and select bold/underline

    See the attached workbook where I have updated the "before" sheet.
    Attached Files Attached Files

  6. #6
    Forum Moderator
    Join Date
    01-21-2014
    Location
    St. Joseph, Illinois U.S.A.
    MS-Off Ver
    Office 365 v 2404
    Posts
    13,406

    Re: Highlight cells, closest to zero and a specified number, and corresponding cells

    Hello joshsrai. Welcome to the forum.

    This uses some megaformulas. Didn't have a helper range strategy.

    For F2:Q5
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    For R2:W5
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    Dave

  7. #7
    Registered User
    Join Date
    01-26-2019
    Location
    south carolina, usa
    MS-Off Ver
    2016
    Posts
    8

    Re: Highlight cells, closest to zero and a specified number, and corresponding cells

    Hi FlameRetired!

    Thanks so much for helping me out
    this is my first time getting into excel

    the two formulas you sent, it really helped me out


    could you explain to me the formulas you posted on the thread??
    i need to apply it to some more rows and a thorough explanation would really help.

    For F2:Q5
    =OR(F2=INDEX($F2:$Q2,MATCH(MIN(IF(--ISNUMBER(FIND("%",$F$1:$Q$1)),ABS($F2:$Q2-1.6))),IF(--ISNUMBER(FIND("%",$F$1:$Q$1)),ABS($F2:$Q2-1.6)),0)),F2=INDEX($F2:$Q2,MATCH(MIN(IF($F$1:$Q$1=-1.6,ABS($F2:$Q2))),IF($F$1:$Q$1=-1.6,ABS($F2:$Q2)),0)))

    For R2:W5
    =AND(INDEX($R2:$W2,MATCH(1000,$R2:$W2,1))=R2,(MATCH(1000,$R2:$W2,1)-1)*2+1=MATCH(MIN(IF(--ISNUMBER(FIND("%",$F$1:$Q$1)),ABS($F2:$Q2-1.6))),IF(--ISNUMBER(FIND("%",$F$1:$Q$1)),ABS($F2:$Q2-1.6)),0))


    thanks again, you're lifesaver FlameRetired!
    joshsrai

  8. #8
    Forum Moderator
    Join Date
    01-21-2014
    Location
    St. Joseph, Illinois U.S.A.
    MS-Off Ver
    Office 365 v 2404
    Posts
    13,406

    Re: Highlight cells, closest to zero and a specified number, and corresponding cells

    joshsrai

    I am sorry for my late response.

    I had a family emergency that required my full attention and lost sight of your post until today.

    could you explain to me the formulas you posted on the thread??
    i need to apply it to some more rows and a thorough explanation would really help.
    As far as applying to more rows all you should need to do is extend the 'Applies to' ranges in CF manager from $F$2:$Q$5 to $F$2:$Q$n as many rows as you require. The same holds for $R$2:$W$5.

    As far as thorough explanation is concerned I will have to revisit the original question and see if I can reconstruct the solution. That will take me a while. There are also limits to how many characters per post.

    In the meantime I would suggest you copy the formula from CF manager for the first range and paste it into a row in column F below the data. Try F7. Then fill across to column Q and down 4 rows. You will have a range of TRUE/FALSE.

    With any of those individual cells active ... probably favor the TRUE cells ... activate the 'Evaluate formula' feature under the Formulas ribbon. Clicking Evaluate repeatedly reveals step-by-step how Excel calculates this. As me explaining this will surely exceed the permitted number of characters in posts this will be a more productive approach to understanding here (and in the future).

    Let me know and post back if you have questions along the way. I am still subscribed to this thread.

    PS I forgot to add that the CF formula used in F7 across and down is an array formula. If you aren’t familiar with array-entered formulas array enter means the formula must be committed from edit mode by simultaneously pressing and holding down Ctrl and Shift while hitting Enter.
    Last edited by FlameRetired; 03-08-2019 at 08:09 PM. Reason: after thought

  9. #9
    Registered User
    Join Date
    01-26-2019
    Location
    south carolina, usa
    MS-Off Ver
    2016
    Posts
    8

    Re: Highlight cells, closest to zero and a specified number, and corresponding cells

    hi guys,

    thank you for all the feedback and help
    it's been great

    i need help with one more thing

    how can i highlight a cell according to a value...
    according to the MOCKBOOK_gw
    if Q1 is the closest to zero, i'd like to give Q1 and P1 a certain format, like a blue font
    or if O2 if the closest to zero, i'd like to give O2 and N2 a certain format, like a purple underlined bold font
    and so on

    thanks you guys!

  10. #10
    Forum Expert
    Join Date
    10-15-2018
    Location
    MA, USA
    MS-Off Ver
    2010, 2019
    Posts
    1,616

    Re: Highlight cells, closest to zero and a specified number, and corresponding cells

    Sorry, but I'm not sure I'm clear on what you are asking. Are you now looking for the smallest values across all columns? So, per MOCKBOOK_gw.xlsx, you are looking for the smallest value out of G4 (=.0187), I4 (=-.0113), K5 (=0.0149), M3 (=0.0374), O3 (=-0.0350), Q2 (=0.0027) which would be Q2?

    If not then please try to clarify.

  11. #11
    Registered User
    Join Date
    01-26-2019
    Location
    south carolina, usa
    MS-Off Ver
    2016
    Posts
    8

    Re: Highlight cells, closest to zero and a specified number, and corresponding cells

    Hi GeoffW283,

    sorry for the confusion
    the original issue/request has already been solved
    but i do need some help in highlighting values...let me explain
    we'll use the MOCKBOOK_gw.xlsx as the example
    In row two, P2 and Q2 are Conditioned Formatted to be underlined and bold because P2 is closest the value 1.6 and Q2 is closest to 0
    In row three, N3 and O3 are Conditioned Formatted to be underlined and bold because N3 is closest the value 1.6 and O3 is closest to 0
    so on and so forth

    the thing i need help with is,
    how do i CF P2 and Q2 to be BLUE(or what ever formatting) and N3 and O3 to be Green...
    i'd like each group (P&Q, N&O, L&M, J&K, H&I, F&G) to have different formatting, i.e. color

    i hope this clarifies...

    thank you again for the help

  12. #12
    Forum Expert
    Join Date
    10-15-2018
    Location
    MA, USA
    MS-Off Ver
    2010, 2019
    Posts
    1,616

    Re: Highlight cells, closest to zero and a specified number, and corresponding cells

    Like this?

    MOCKBOOK_CF.png

  13. #13
    Registered User
    Join Date
    01-26-2019
    Location
    south carolina, usa
    MS-Off Ver
    2016
    Posts
    8

    Re: Highlight cells, closest to zero and a specified number, and corresponding cells

    Yes sir!
    here's the formula i used to get the lowest value to 1.6
    =ABS(F2)=MIN(ABS($G2),ABD($J2),ABS($M2),ABS($P2),ABS($S2),ABS($V2),ABS($Y2))

  14. #14
    Forum Expert
    Join Date
    10-15-2018
    Location
    MA, USA
    MS-Off Ver
    2010, 2019
    Posts
    1,616

    Re: Highlight cells, closest to zero and a specified number, and corresponding cells

    I'm not sure what you are telling me with the formula. The "1.6" columns are G, I, K, M, O, Q (at least in MOCKBOOK_gw.xlsx). Your formula is looking at G, J, M, P, S which is a mixture of column types.

    Relative to MOCKBOOK_gw.xlsx the conditional formatting formulas are simply =N2=N$13, -P2=P$13 etc. as shown in post 12.

    Are you trying to adapt the conditional formatting to Dave's post #6 formulas which dispensed with the helper row 13 (which I rely on for the answer I provided) ??

  15. #15
    Registered User
    Join Date
    01-26-2019
    Location
    south carolina, usa
    MS-Off Ver
    2016
    Posts
    8

    Re: Highlight cells, closest to zero and a specified number, and corresponding cells

    i've uploaded an updated version "MOCKBOOK_gw_2" with desensitized data in it

    if Columns F and G are the closest to 1.6 and zero, respectively, then it should be filled purple with white font.

    if Columns I and J are the closest to 1.6 and zero, respectively, then the border should be red with black font.

    if Columns L and M are the closest to 1.6 and zero, respectively, then it should be filled green with black font.

    if Columns O and P are the closest to 1.6 and zero, respectively, then it should be filled black with white font.

    if Columns R and S are the closest to 1.6 and zero, respectively, then it should be filled yellow with black font.

    if Columns U and V are the closest to 1.6 and zero, respectively, then it should be filled Pink with black font.


    hope this helps
    Attached Files Attached Files

  16. #16
    Forum Expert
    Join Date
    10-15-2018
    Location
    MA, USA
    MS-Off Ver
    2010, 2019
    Posts
    1,616

    Re: Highlight cells, closest to zero and a specified number, and corresponding cells

    First, you had about a hundred CF rules on the C276 Percentages sheet - FYI I have removed these in the attached workbook.

    As you want different formatting for each pair of cell columns then there has to be separate CF rules for each pair if columns.
    Here is the formula for F3:G10
    Formula: copy to clipboard
    Please Login or Register  to view this content.

    Here is the rule for I3:J10:
    Formula: copy to clipboard
    Please Login or Register  to view this content.

    The formula for the additional column pairs is similar - the only change is $G3 >> $J3 >> $M3 etc.
    In the attached file I have implemented these formulas and your required formatting for F:G and I:J.

    Let me know if I have understood your requirement correctly. If so then I will leave it to you to complete the remainder of the column pairs!
    Attached Files Attached Files

+ 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. > number 4 entries in range of cells then highlight
    By ORIELSON in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 06-29-2015, 11:14 AM
  2. Highlight cells based on number
    By cossie2k in forum Excel Formulas & Functions
    Replies: 13
    Last Post: 05-29-2015, 12:24 PM
  3. [SOLVED] Count cells in row based on cell value, highlight row if wrong number or cells.
    By gutterball in forum Excel Programming / VBA / Macros
    Replies: 8
    Last Post: 09-11-2014, 04:00 PM
  4. Replies: 3
    Last Post: 07-28-2014, 06:08 PM
  5. [SOLVED] highlight a series of cells based on the number of days in a date range
    By b2lynch in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 06-09-2014, 10:48 PM
  6. [SOLVED] How do i highlight a cell that is the closest number to a different cell.
    By dbravo in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 04-04-2014, 03:59 PM
  7. use vba to highlight closest number match
    By Toidz77 in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 09-07-2009, 12:55 PM

Tags for this Thread

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