+ Reply to Thread
Results 1 to 7 of 7

Adding a date to the bottom of a list and finding the correct cell

Hybrid View

  1. #1
    Registered User
    Join Date
    09-12-2013
    Location
    Kent, England
    MS-Off Ver
    Excel 2010
    Posts
    67

    Adding a date to the bottom of a list and finding the correct cell

    Hi.

    I have two problems sort of rolled into one. I have a spreadsheet with a list of skills to perform in cells a2:z2. Under those I put in dates where those skills are performed so a3:a100 , b3:b100 and so on. At the moment I have the these dates populating another sheet with the list of skills going a2:a200 and the dates in b2:b200. Annoyingly I have been asked set it up so it inputs the other way so my problems are: The skills in the second sheet are in a different order than in the first sheet so its not a straight collrelation between the two so I would need to search for the title and match it to the second sheet. Then the second problem is as the will be numerous entries I need to find the next availible space in the first sheet. So can you add data at the bottom of a list??
    Is this all possible??

    Thank you

  2. #2
    Forum Guru Kaper's Avatar
    Join Date
    12-14-2013
    Location
    Warsaw, Poland
    MS-Off Ver
    most often: Office 365 in Windows environment
    Posts
    8,863

    Re: Adding a date to the bottom of a list and finding the correct cell

    It all sounds possible, but with sample workbook it would be easy to give precise suggestions.
    Without, I expect that MATCH and OFFSET functions can do miracles for you ;-)
    Best Regards,

    Kaper

  3. #3
    Registered User
    Join Date
    09-12-2013
    Location
    Kent, England
    MS-Off Ver
    Excel 2010
    Posts
    67

    Re: Adding a date to the bottom of a list and finding the correct cell

    This isn't the actual file but is sort of what I need. Hope that helps. If you can imagine a lot more skills on sheet one and a lot more entry points on sheet 2

    Thank you
    Attached Files Attached Files

  4. #4
    Forum Guru Kaper's Avatar
    Join Date
    12-14-2013
    Location
    Warsaw, Poland
    MS-Off Ver
    most often: Office 365 in Windows environment
    Posts
    8,863

    Re: Adding a date to the bottom of a list and finding the correct cell

    Hi,
    If I understand well, you want your data from sheet2 to be added to existing data in sheet1.
    That would not be possible with formulas. Formula gar=thers information from "surrounding world" and presents it (somehow processed) in the cell where is written in.
    but it can be easily done with a macro.
    I had some spare time, so prepared a but more fancy one (although still rather on easy side):
    Sub test()
    Const DeleteAfterUse = True
    Dim i As Long, LastColumn As Range, DestinationColumn As Range, ErrMsg As String
    Application.ScreenUpdating = False
    With Sheets("Sheet1")
      Set LastColumn = .Range("A1").End(xlToRight)
      For i = 1 To Cells(Rows.Count, "B").End(xlUp).Row
        If IsDate(Cells(i, "B")) Then
          Set DestinationColumn = Range(.Range("A1"), LastColumn).Find(what:=Trim(Cells(i, "A")), _
          lookat:=xlWhole)
          If DestinationColumn Is Nothing Then
            ErrMsg = ErrMsg & "Not found" & Cells(i, "A") & " from row: " & i & vbNewLine
          Else
            .Cells(.Rows.Count, DestinationColumn.Column).End(xlUp).Offset(1, 0) = Cells(i, "B")
            If DeleteAfterUse Then Cells(i, "A").Resize(1, 2).ClearContents
          End If
        Else
          ErrMsg = ErrMsg & "non-date value: " & IIf(Len(Cells(i, "B")) > 20, Left(Cells(i, "B"), 17) _
            & "...", Cells(i, "B")) & " in row: " & i & vbNewLine
        End If
      Next i
    End With
    If Len(ErrMsg) > 0 Then MsgBox ErrMsg, vbCritical, "..:: Errors List! ::.."
    Application.ScreenUpdating = True
    End Sub
    see how it works in the attachment.

    some comments
    - I think that after succesfull writing into main sheet data shall be deleted from suplementary one. If not, change DeleteAfterUse to False
    - Lines with errors (either wrong headings or not-excel-dates will remain not deleted for correction.
    - Much larger sheets (but with the same general layout) shall work well. Key points are:
    - headers in main sheet starting at A1
    - names and dates in supplementary sheet in columns A and B starting from row 1
    - Dates are real excel dates: "January 1st, 2014" won't do
    - Headers in main sheet are "neat" - now Skill G is written as "Skill G " (with space at the end) - and this will cause errors (in supplementary sheet it is OK)
    Attached Files Attached Files

  5. #5
    Registered User
    Join Date
    09-12-2013
    Location
    Kent, England
    MS-Off Ver
    Excel 2010
    Posts
    67

    Re: Adding a date to the bottom of a list and finding the correct cell

    Thank you for that. It's amazing how much work people put into replies they give.
    Totally understand your point about formulas being gatherers of information so was wondering doing it the other way around. In the sheet I sent I want the dates entered in sheet 2 into sheet 1 in the correct place.
    Using MATCH (im not entirely sure on the syntax) could you say for skill A have a formula in a2 saying match a1 to sheet2 a1:14 if the matched cell has a corresponding date in the next cell then return that date. Now questions i would ask are if there is more that one result which result would it return?
    Then for the next cells down in this case sheet 1 a3 a4 a5 and so on you can just have an if statement so if the cell above is empty it wont look for anything if not then do the same matching process ignoring the result found in the cell above. Does that make sence??

    Neil

  6. #6
    Forum Guru Kaper's Avatar
    Join Date
    12-14-2013
    Location
    Warsaw, Poland
    MS-Off Ver
    most often: Office 365 in Windows environment
    Posts
    8,863

    Re: Adding a date to the bottom of a list and finding the correct cell

    OK, so we have a list of headers (skil names for columns) in Sheet1 (no dates yet) and list of Skills with dates in Sheet2 -> we want to transfer it to Sheet1 with formulas.
    Let's start with approach suggested by you, so in A2 in Sheet1:

    =IF(COUNTIF(Sheet2!$A:$A,A$1)=0,"",INDEX(Sheet2!$B:$B,MATCH(A$1,Sheet2!$A:$A,0)))

    first we check if there is any data for skill in the header (with COUNTIF) then with MATCH (you asked about it) we find the first occurence of our skill in column A and return respective date from column B using INDEX. With reasonable use of mixed and absolute addressing our formula is ready to be copied right.

    If we do it we notice some strange dates like Jan 0 1900 in cells where we expected empty string ("").
    To deal with it we can format the cells (all where we want our formulas, so A2:I10 or something like as non-standard format - for instance mm/dd/yyyy,,,@ or dd-mm-yyyy,,,@ (as I did). Note that excel can later show only dd-mm-yyyy,@ but at the stage of appying you shall write the long form:
    positivevaluesformat,negativevaluesformat,zerovaluesformat,textformat
    or at least a part of it

    OK, that was good for first date, but MATCH will always find first occurence, so it is not good way for next.
    We can try array formula (committed with Ctrl+Shift+Enter) for A3:
    =IF(COUNTIF(Sheet2!$A:$A,A$1)<ROW(A2),"",INDEX(Sheet2!$B:$B,SMALL(IF(Sheet2!$A:$A=A$1,ROW($A:$A),""),ROW(A2))))

    COUNTIF part is similar - as we plan to copy it down we do not check if countif<2 (= 0 or 1) but <ROW(A2) as we will copy it down will be rownumber of A3, A4 and so on.
    INDEX is again used to retieve date from column B, but it's location is determined with second (row(a2) smallest row number, where our skill was in column A

    This way is also good for row above, so we could copy it here too (in attachment I didn't).

    if we copy it to few cells down and right we will notice that excel slows down. Especially Excell2007+ this is because formula checks whole columns (and there is a million+ rows!)

    so let's edit A4 to look into only reasonable (I used 100 but adopt it to your needs) rows:

    =IF(COUNTIF(Sheet2!$A$1:$A$100,A$1)<ROW(A3),"",INDEX(Sheet2!$B$1:$B$100,SMALL(IF(Sheet2!$A$1:$A$100=A$1,ROW($A$1:$A$100),""),ROW(A3))))

    and remember - array formula ! (Ctrl+Shift+Enter)

    This one can be copied to a number of cells not slowing excel down noticeably.

    In Attachment you have first formula left in A2 and second in A3 (just to examine them) and all others (A4:A10 and B2:I10) is the third formula.

    Wow, that was long ...
    Attached Files Attached Files

  7. #7
    Registered User
    Join Date
    09-12-2013
    Location
    Kent, England
    MS-Off Ver
    Excel 2010
    Posts
    67

    Re: Adding a date to the bottom of a list and finding the correct cell

    Wow thats brilliant thank you. Been off work for last week but when back will definatly ty to input all that and let you know how it works
    Thank you

    Neil

+ 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. Replies: 3
    Last Post: 10-21-2013, 11:36 PM
  2. Need Macro for finding date in cell and adding data
    By evilr34 in forum Excel Programming / VBA / Macros
    Replies: 5
    Last Post: 03-15-2013, 11:15 AM
  3. Replies: 1
    Last Post: 08-13-2012, 11:18 AM
  4. Replies: 6
    Last Post: 10-30-2011, 04:14 AM
  5. Adding data to the bottom of a list
    By Jon_Hanes in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 03-29-2011, 02:20 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