+ Reply to Thread
Results 1 to 12 of 12

Conditional formatting expanding across a year

  1. #1
    Registered User
    Join Date
    11-10-2022
    Location
    Aalborg, Denmark
    MS-Off Ver
    Excel M365
    Posts
    19

    Conditional formatting expanding across a year

    Hi all,

    With help from youtube videos and this forum i've created a gant chart in Excel which uses conditional formatting. I've run into a problem i cannot fix myself.

    In the attached file the conditional formatting wont color the column which represents the first week in a year.

    2024-08-09 13_11_08-Tidsplan_skabelon_4.0.xlsx - Excel.png

    Can someone help me fix the formula?
    Attached Files Attached Files

  2. #2
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (both in England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2507 (Windows 11 Home 24H2 64-bit)
    Posts
    91,665

    Re: Conditional formatting expanding across a year

    I think it's because of the mismatch of week number (1) with 30 December (which would be week 52), but I don't fully understand the formula that you are using.

    Explain in WORDS what you are expecting it to do.
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help. It's a universal courtesy.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    NB:
    as a Moderator, I never accept friendship requests.
    Forum Rules (updated August 2023): please read them here.

  3. #3
    Registered User
    Join Date
    11-10-2022
    Location
    Aalborg, Denmark
    MS-Off Ver
    Excel M365
    Posts
    19

    Re: Conditional formatting expanding across a year

    I've gotten help with the formula so i dont understand it fully either tbh.

    The formula needs to color the range between the first and last week. When spanning across a year (start 2024 and end in 2025 for example) it won't color week 1. If that could be possible it would be perfect.

  4. #4
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (both in England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2507 (Windows 11 Home 24H2 64-bit)
    Posts
    91,665

    Re: Conditional formatting expanding across a year

    OK - I'll have a look.

  5. #5
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (both in England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2507 (Windows 11 Home 24H2 64-bit)
    Posts
    91,665

    Re: Conditional formatting expanding across a year

    I've tried changing the rule to this:

    =AND(VALUE(YEAR(M$17+6)&TEXT(M$16,"00"))>=VALUE($J19&TEXT($I19,"00")),VALUE(YEAR(M$17+6)&TEXT(M$16,"00"))<=VALUE($L19&TEXT($K19,"00")))

    Seems to work. Please check it carefully.

  6. #6
    Forum Expert
    Join Date
    01-05-2013
    Location
    Singapore
    MS-Off Ver
    H&B2019
    Posts
    4,542

    Re: Conditional formatting expanding across a year

    Try, CF formula:
    =MEDIAN($J18*100+$I18,$L18*100+$K18,YEAR(M$17)*100+M$16)=YEAR(M$17)*100+M$16
    applies to: $M$18:$BL$47

  7. #7
    Registered User
    Join Date
    11-10-2022
    Location
    Aalborg, Denmark
    MS-Off Ver
    Excel M365
    Posts
    19

    Re: Conditional formatting expanding across a year

    AliGW's solution worked - haven't tried yours josephteh.

    Sorry for expanding on the thread, but do you guys know if it would be relatively easy to make another to columns in where i can define the interval of weeks that shouldnt be formatted from the formula? Example: Over the holidays (marked by the orange diagonal line formatting) it would be great, if the cell wasnt colored blue.

  8. #8
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (both in England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2507 (Windows 11 Home 24H2 64-bit)
    Posts
    91,665

    Re: Conditional formatting expanding across a year

    Move the holiday rule to the top of the CF list and tick Stop If True.

    Glad to have helped.

    If that takes care of your original question, please choose Thread Tools from the menu link above and mark this thread as SOLVED. You can also access the SOLVED tag by editing the opening post and choosing SOLVED from the drop-down to the left of the title box.

    Also, if you have not already done so, remember that you can reward anyone who offered you help towards a solution for your issue by clicking the small star icon (* Add Reputation) located in the lower left corner of the post in which the help was given. By doing so you can add to the reputation(s) of each of those who offered help.
    Last edited by AliGW; 08-11-2024 at 07:08 AM.

  9. #9
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (both in England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2507 (Windows 11 Home 24H2 64-bit)
    Posts
    91,665

    Re: Conditional formatting expanding across a year

    Thanks for the rep.

  10. #10
    Forum Expert bebo021999's Avatar
    Join Date
    07-22-2011
    Location
    Vietnam
    MS-Off Ver
    Excel 2016
    Posts
    9,674

    Re: Conditional formatting expanding across a year

    Quote Originally Posted by CHIPROCKETS View Post
    haven't tried yours josephteh.
    About post #6:
    I haven't tried it yet, but it seems that his answer is very promising (With MEDIAN, to get the medium date).
    When you have multiple answers to consider, try to test them all, whether they are correct or incorrect,
    to show respect for the time the person who helped you has invested.
    Good luck
    Quang PT

  11. #11
    Forum Expert
    Join Date
    01-05-2013
    Location
    Singapore
    MS-Off Ver
    H&B2019
    Posts
    4,542

    Re: Conditional formatting expanding across a year

    To exclude holiday weeks, =AND(MEDIAN($J18*100+$I18,$L18*100+$K18,YEAR(M$17)*100+M$16)=YEAR(M$17)*100+M$16,NOT(ISNUMBER(MATCH(M$16,Inputs!$B$3:$B$12,0))))

    And, your CF for holiday weeks can be shortened to: =ISNUMBER(MATCH(M$16,Inputs!$B$3:$B$12,0))

  12. #12
    Forum Expert
    Join Date
    01-05-2013
    Location
    Singapore
    MS-Off Ver
    H&B2019
    Posts
    4,542

    Re: Conditional formatting expanding across a year

    Thanks Quang! I learned that from one of the experts here! I believe I have seen both you and Ali used that method before.

+ 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. [SOLVED] Conditional Formatting for dates to expire in 1 year
    By rileytto in forum Excel Formulas & Functions
    Replies: 8
    Last Post: 09-02-2020, 03:09 PM
  2. [SOLVED] Conditional formatting only month and day, not year
    By asabur6 in forum Excel General
    Replies: 5
    Last Post: 11-01-2019, 07:56 AM
  3. [SOLVED] Conditional Formatting for five and ten year milestones
    By MULegacy in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 09-05-2017, 03:28 PM
  4. Conditional formatting problem with 'applies to' when expanding a range
    By gtol in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 03-29-2013, 07:18 PM
  5. Expanding 4th quarter by month ONLY for certain year
    By Melvinrobb in forum Excel Charting & Pivots
    Replies: 0
    Last Post: 02-28-2013, 06:13 PM
  6. Replies: 4
    Last Post: 06-23-2011, 11:45 AM
  7. Conditional Formatting more than one year old
    By Stormdancing in forum Excel - New Users/Basics
    Replies: 1
    Last Post: 02-29-2008, 04:33 AM

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