VBA copy cells based on text string

collirde

New Member
Joined
Mar 13, 2016
Messages
8
Hello and I hope I can find a little help. I know just enough VBA to get myself running down rabbit holes trying to figure things out.

I have a sheet that I want to create another sheet from the info on it. I need to create a new sheet "SUBLIST" and for each teacher in Column B, I need to make a separate row for each block they will need a substitute (looking in column D "Time Out"). If they have a 1, then I need the info from Class1 and Room1 along with the substitute's name from column V. Then do the same for 2, Class2 and Room2 along with the name of the sub. Continue this for 3 and 4.

Any help would be appreciated as I am trying to help a co-worker out and simplify their daily routine.

Thanks in advance.

Ray



Starting Sheet:

1603814991899.png


What I am hoping to get in a new sheet:
1603818586278.png
 
See if this meets your needs, if not let me know.

VBA Code:
Public Sub Collirde_r3()

    Const cSourceSheet      As String = "Sheet1"     ' << Change sheet names as required
    Const cDestinationSheet As String = "SUBLIST2"

    Dim oWsSrc  As Worksheet
    Dim oWsDest As Worksheet
    Dim rng     As Range
    Dim arrIN   As Variant
    Dim arrOUT  As Variant
    Dim r       As Long
    Dim n       As Long
    Dim lRow    As Long
    Dim iMax    As Integer
    Dim iBlock  As Integer

    ' unconditionally delete any pre-existing target worksheet
    For Each oWsDest In ThisWorkbook.Sheets
        If StrComp(cDestinationSheet, oWsDest.Name, vbTextCompare) = 0 Then
            Application.DisplayAlerts = False
            oWsDest.Delete
            Application.DisplayAlerts = True
            Exit For
        End If
    Next

    ' provide a blank target worksheet
    With ThisWorkbook
        Set oWsDest = .Sheets.Add(after:=.Sheets(.Sheets.Count))
    End With
    oWsDest.Name = cDestinationSheet

    ' allocate memory for source data and perform copy
    Set oWsSrc = ThisWorkbook.Sheets(cSourceSheet)
    With oWsSrc
        ' [] this part determines which area within column B has actually been used, starting from cell B3 and downwards
        ' [] since column B is just one column, Resize statement is used to extend the primary result with some adjacent
        '    columns at the right hand side, from 1 (col B) to 22 (col W)
        ' [] the secundary result is a consecutive worksheet area, a matrix with ??? rows and 22 columns
        ' [] all values of that area are copied into a memory matrix (to increase performance), ie assigned to an array with the name arrIN
        arrIN = .Range("B3", .Cells(.Rows.Count, "B").End(xlUp)).Resize(, 22)
    End With

    ' read source data
    For r = 1 To UBound(arrIN, 1)                   ' [] r represents the "row" number within our memory matrix and is increased by one every turn (Next r)
        iMax = Len(arrIN(r, 3))                     ' [] "column" 3 (on "row" r) of our matrix contains the "Time Out" numbers without delimiters, so determine how many numbers there are
        ' allocate memory for destination data
        ReDim arrOUT(1 To iMax, 1 To 6)             ' [] prepare a memory matrix with iMax rows and 6 columns for the purpose of output on destination sheet
        ' rearrange destination data
        For n = 1 To iMax                           ' [] on every turn (Next n) fill each row r with the required output
            iBlock = Mid(arrIN(r, 3), n, 1)         ' [] isolate from row r, column 3 (containing the "Time Out" numbers without delimiters), the required n-th number (length 1) and assign result to iBlock variable
            arrOUT(n, 1) = arrIN(r, 1)              ' [] copy NAME               (column 1) to output matrix (row n, column 1)
            arrOUT(n, 2) = iBlock                   ' [] copy isolated TIME OUT number      to output matrix (row n, column 2)
            arrOUT(n, 5) = arrIN(r, 21)             ' [] copy INC & TA          (column 21) to output matrix (row n, column 5)
            arrOUT(n, 6) = arrIN(r, 22)             ' [] copy SUBSTITUTE'S NAME (column 22) to output matrix (row n, column 6)
            Select Case iBlock
                Case 1                              ' [] depending on TIME OUT number, do copy ....
                    arrOUT(n, 3) = arrIN(r, 6)      ' [] ... row r, column 6 (Class 1)  to output matrix
                    arrOUT(n, 4) = arrIN(r, 7)      ' [] ... row r, column 7 (Room 1)
                Case 2
                    arrOUT(n, 3) = arrIN(r, 9)      ' [] etc.
                    arrOUT(n, 4) = arrIN(r, 10)
                Case 3
                    arrOUT(n, 3) = arrIN(r, 12)
                    arrOUT(n, 4) = arrIN(r, 13)
                Case 4
                    arrOUT(n, 3) = arrIN(r, 15)
                    arrOUT(n, 4) = arrIN(r, 16)
            End Select
        Next n
       
        ' determine destination area on sheet and paste rearranged data
        ' [] this part determines the first cell of the area within column A, which area is needed to paste the output to
        ' [] the resulting cell has to be extended (resized) with a certain number of rows and a certain number of columns so the arrOUT data fits in
        ' [] the 3 represents worksheet row to start with (row 2 contains headers) and is increased by value lRow on every turn (Next r)
        ' [] the iMax represents the number of needed rows, the 6 represents the number of needed columns
        ' [] finally, assign resulting worksheet area to the variable with the name rng
        Set rng = oWsDest.Range("A" & 3 + lRow).Resize(iMax, 6)
       
        ' [] all values previously placed in memory matrix are pasted into the above determined worksheet area.
        rng = arrOUT
        ' [] adjust target row to start with, with amount of already used rows
        lRow = lRow + iMax
    Next r

    ' finally create some headers
    With oWsDest.Range("A2:F2")
        .Font.Bold = True
        .EntireColumn.HorizontalAlignment = xlCenter
        .Cells(, 1).EntireColumn.HorizontalAlignment = xlGeneral
        ' [] within .Cells(row, column) the row number is omitted, so use the only and one row within range ("A2:F2")
        .Cells(, 1) = "Teacher Name"
        .Cells(, 2) = "Block"
        .Cells(, 3) = "Class"
        .Cells(, 4) = "Room"
        .Cells(, 5) = "Inc and TA"
        .Cells(, 6) = "Sub's Name"
    End With
    rng.EntireColumn.AutoFit
End Sub
This is above and beyond!!!!!! I really can't begin to thank you enough for taking the time to help a complete stranger, it shows what a team player you are and willing to help. I was able to figure it out with your comments.

Thanks,
Ray
 
Upvote 0

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
You are most welcome Ray, and thanks for letting me know.
Your clear explanation of the expected result has certainly contributed to this solution.
 
Upvote 0

Forum statistics

Threads
1,215,040
Messages
6,122,806
Members
449,095
Latest member
m_smith_solihull

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top