+ Reply to Thread
Results 1 to 3 of 3

When pattern changes...?

Hybrid View

  1. #1
    Registered User
    Join Date
    10-02-2013
    Location
    London, UK
    MS-Off Ver
    Excel 365
    Posts
    42

    When pattern changes...?

    Hello,

    could somebody help me with the following problem:
    In the excel file I have attached, there are 5 different patterns of 4 factors.
    I would like that I get the dates when a pattern start or change to the next one. (Solution for the certain example in column F)

    Is there any formula I can use?

    Thanks in advance!
    Attached Files Attached Files

  2. #2
    Forum Expert
    Join Date
    02-11-2014
    Location
    New York
    MS-Off Ver
    Excel 365 (Windows)
    Posts
    6,258

    Re: When pattern changes...?

    In cell F2, enter the formula

    =IF(OR(B1<>B2,C1<>C2,D1<>D2,E1<>E2),ROW(),"")

    and copy down to match column E.

    Then format G2 as a date, and use the formula

    =IFERROR(INDEX(A:A,MATCH(SMALL(F:F,ROW(A1)),F:F,FALSE)),"")

    and copy down to match column F, or until you get blanks.
    Last edited by Bernie Deitrick; 08-02-2015 at 09:55 AM.
    Bernie Deitrick
    Excel MVP 2000-2010

  3. #3
    Forum Expert newdoverman's Avatar
    Join Date
    02-07-2013
    Location
    Port Dover, Ontario, Canada
    MS-Off Ver
    2010
    Posts
    10,330

    Re: When pattern changes...?

    This uses basically the same logic but a slightly different approach:
    To get the dates for the transitions, the values in the columns are mated vertically. When they don't match, then the next "set" is started and the date is noted.
    This formula will see the difference in the "sets" and bring the date to column F using OFFSET to get the date from column A. Format column F for dates and enter this in F2 and fill down:
    Formula: copy to clipboard
    =IF(OR(B1<>B2,C1<>C2,D1<>D2,E1<>E2),OFFSET(F2,0,-5,1,1),"")


    The dates are now in column F. To condense this column of dates, format column G as dates and enter this array formula in G2 and fill down. This just takes the data in column F and eliminates the blank cells.
    Formula: copy to clipboard
    =IFERROR(INDEX($F$2:$F$17,SMALL(IF($F$2:$F$17<>"",ROW($F$2:$F$17)-MIN(ROW($F$2:$F$17))+1),ROWS($1:1))),"")

    ...confirmed by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. You will know the array is active when you see curly braces { } appear around your formula. If you do not CTRL+SHIFT+ENTER you will get an error or a clearly incorrect answer. Press F2 on that cell and try again.

    A
    B
    C
    D
    E
    F
    G
    1
    Date
    X
    Y
    Z
    W
    SOLUTION
    2
    01/07/2010
    TRUE
    FALSE
    TRUE
    FALSE
    01/07/2010
    01/07/2010
    3
    23/12/2010
    FALSE
    FALSE
    TRUE
    FALSE
    23/12/2010
    23/12/2010
    4
    05/06/2011
    FALSE
    FALSE
    TRUE
    FALSE
    23/11/2011
    5
    09/10/2011
    FALSE
    FALSE
    TRUE
    FALSE
    23/12/2012
    6
    23/11/2011
    TRUE
    FALSE
    FALSE
    FALSE
    23/11/2011
    04/04/2014
    7
    02/03/2012
    TRUE
    FALSE
    FALSE
    FALSE
    8
    05/05/2012
    TRUE
    FALSE
    FALSE
    FALSE
    9
    06/07/2012
    TRUE
    FALSE
    FALSE
    FALSE
    10
    23/12/2012
    FALSE
    TRUE
    FALSE
    FALSE
    23/12/2012
    11
    02/05/2013
    FALSE
    TRUE
    FALSE
    FALSE
    12
    04/06/2013
    FALSE
    TRUE
    FALSE
    FALSE
    13
    02/11/2013
    FALSE
    TRUE
    FALSE
    FALSE
    14
    05/02/2014
    FALSE
    TRUE
    FALSE
    FALSE
    15
    04/04/2014
    FALSE
    FALSE
    FALSE
    TRUE
    04/04/2014
    16
    22/07/2014
    FALSE
    FALSE
    FALSE
    TRUE
    17
    12/05/2015
    FALSE
    FALSE
    FALSE
    TRUE
    <---------If you like someone's answer, click the star to the left of one of their posts to give them a reputation point for that answer.
    Ron W

+ 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. Macro to insert pattern based on value and select based on pattern
    By CB569 in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 01-15-2015, 12:36 PM
  2. [SOLVED] Lookup and return rows based on pattern start and pattern end
    By JDI in forum Excel General
    Replies: 18
    Last Post: 11-16-2014, 11:44 PM
  3. [SOLVED] formula with a pattern - how to?
    By mbeekvelt in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 08-23-2014, 04:29 AM
  4. Copy down hypertext cell range pattern & cell reference formula pattern
    By Underexcelling in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 01-10-2014, 03:23 AM
  5. [SOLVED] Finding a pattern
    By ChiknNuggets in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 07-21-2013, 10:26 PM
  6. pattern matching possible?
    By vito in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 05-16-2006, 12:10 PM

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