macro / vba assistance

Rameses

Board Regular
Joined
Mar 3, 2010
Messages
137
:confused:

Dear all

Worksheet 1 is a data set

Worksheet 2 is a form template with cells to be filled from row 2 of worksheet 1

Once that is filled in I want to be able to save that and open a new worksheet with the form template to fill in row 3 of worksheet 1 (this can all be saved in the same workbook)

I need a macro but dont know where to start

any assistance gratefully received

rameses
 

Excel Facts

Convert text numbers to real numbers
Select a column containing text numbers. Press Alt+D E F to quickly convert text to numbers. Faster than "Convert to Number"
Re: URGENT macro / vba assistance

Dear all


PLease may you provide assistance with what I need to Jerrys code to made it more specific (Thank you Jerry for your code)

I wish to copy some data from Row 1 on my data Sheet to my Template

Specifically


A2 (data) to C2 (Template) >this is a surname
B2 (data) also to C2 (Template) >this is a firstname
C2 (data) to C6 (Template)
D2 (data) to C5 (Template)
F2 (data) to B12 (Template)
G2 (data) to C12 (Template)
H2 (data) to D12 (Template)
I2 (data) to E12 (Template)
K2 (data) to F12 (Template)
L2 (data) to G12 (Template)
M2 (data) to H12 (Template)
N2 (data) to I12 (Template)
P2 (data) to J12 (Template)
Q2 (data) to K12 (Template)
R2 (data) to L12 (Template)
S2 (data) to M12 (Template)
U2 (data) to B16 (Template)
V2 (data) to C16 (Template)
W2 (data) to D16 (Template)
X2 (data) to E16 (Template)
Z2 (data) to F16 (Template)
AA2 (data) to G16 (Template)
AB2 (data) to H16 (Template)
AC2 (data) to I16 (Template)
AE2 (data) to J16 (Template)
AF2 (data) to K16 (Template)
AG2 (data) to L16 (Template)
AH2 (data) to M16 (Template)
AJ2 (data) to B20 (Template)
AK2 (data) to C20 (Template)
AL2 (data) to D20 (Template)
AM2 (data) to E20 (Template)
AO2 (data) to F20 (Template)
AP2 (data) to G20 (Template)
AQ2 (data) to H20 (Template)
AR2 (data) to I20 (Template)
AT2 (data) to J20 (Template)
AU2 (data) to K20 (Template)
AV2 (data) to L20 (Template)
AW2 (data) to M20 (Template)


Having copied this I then want to save this as a worksheet (in the same workbook) with the worksheet title being whats in cell A2 (of data sheet)

I then want to open up another template in the same workbook with the title from A3 (of data sheet).

On this template i want to copy row 3 in exctly the same order as the previous

I need to do this 69 times!
ie. from row 2 to row 70

I know that Jerry's code provides the answer but dont know how to make it meet my needs

any assistance gratefully received

rameses
 
Upvote 0
I tried the following to work out the steps but no joy... unfortunately a novice!

Option Explicit
Sub FillOutTemplate()
Dim LastRw As Long, Rw As Long, Cnt As Long
Dim dSht As Worksheet, tSht As Worksheet
Dim MakeBooks As Boolean, SavePath As String
Application.ScreenUpdating = False 'speed up macro execution
Application.DisplayAlerts = False 'no alerts, default answers used
Set dSht = Sheets("Data") 'sheet with data on it starting in row2
Set tSht = Sheets("Template") 'sheet to copy and fill out
'Determine last row of data then loop through the rows one at a time
LastRw = dSht.Range("A70").End(xlUp).Row

For Rw = 2 To LastRw
tSht.Copy After:=Worksheets(Worksheets.Count) 'copy the template
With ActiveSheet 'fill out the form
'edit these rows to fill out your form, add more as needed
.Name = dSht.Range("A" & Rw)
.Range("A2").Value = dSht.Range("C2").Value
.Range("B2").Value = dSht.Range("C2").Value
.Range("C2").Value = dSht.Range("C6").Value
End With


MsgBox "Worksheets created: " & Cnt
Application.ScreenUpdating = True
End Sub
 
Upvote 0
The more i fiddle the more i see have seen partly where i went wrong above but still tyring!!!

any help..?
 
Upvote 0
OK so i was not sure how to concantate the name and surname ina vba... but i have amended jerry's code to the following ... here goes!


Option Explicit
Sub FillOutTemplate()
'Jerry Beaucaire 4/25/2010
'From Sheet1 data fill out template on sheet2 and save
'each sheet as its own file.
Dim LastRw As Long, Rw As Long, Cnt As Long
Dim dSht As Worksheet, tSht As Worksheet
Dim MakeBooks As Boolean, SavePath As String
Application.ScreenUpdating = False 'speed up macro execution
Application.DisplayAlerts = False 'no alerts, default answers used
Set dSht = Sheets("Data") 'sheet with data on it starting in row2
Set tSht = Sheets("Template") 'sheet to copy and fill out
'Option to create separate workbooks
MakeBooks = MsgBox("Create separate workbooks?" & vbLf & vbLf & _
"YES = template will be copied to separate workbooks." & vbLf & _
"NO = template will be copied to sheets within this same workbook", _
vbYesNo + vbQuestion) = vbYes
If MakeBooks Then 'select a folder for the new workbooks
MsgBox "Please select a destination for the new workbooks"
Do
With Application.FileDialog(msoFileDialogFolderPicker)
.AllowMultiSelect = False
.Show
If .SelectedItems.Count > 0 Then 'a folder was chosen
SavePath = .SelectedItems(1) & "\"
Exit Do
Else 'a folder was not chosen
If MsgBox("Do you wish to abort?", _
vbYesNo + vbQuestion) = vbYes Then Exit Sub
End If
End With
Loop
End If
'Determine last row of data then loop through the rows one at a time
LastRw = dSht.Range("A" & Rows.Count).End(xlUp).Row

For Rw = 2 To LastRw
tSht.Copy After:=Worksheets(Worksheets.Count) 'copy the template
With ActiveSheet 'fill out the form
'edit these rows to fill out your form, add more as needed
.Name = dSht.Range("A" & Rw)
.Range("C2").Value = dSht.Range("A" & Rw).Value
.Range("F2").Value = dSht.Range("B" & Rw).Value
.Range("C6").Value = dSht.Range("C" & Rw).Value
.Range("C5").Value = dSht.Range("D" & Rw).Value
.Range("B12").Value = dSht.Range("F" & Rw).Value
.Range("C12").Value = dSht.Range("G" & Rw).Value
.Range("D12").Value = dSht.Range("H" & Rw).Value
.Range("E12").Value = dSht.Range("I" & Rw).Value
.Range("F12").Value = dSht.Range("K" & Rw).Value
.Range("G12").Value = dSht.Range("L" & Rw).Value
.Range("H12").Value = dSht.Range("M" & Rw).Value
.Range("I12").Value = dSht.Range("N" & Rw).Value
.Range("J12").Value = dSht.Range("P" & Rw).Value
.Range("K12").Value = dSht.Range("Q" & Rw).Value
.Range("L12").Value = dSht.Range("R" & Rw).Value
.Range("M12").Value = dSht.Range("S" & Rw).Value
.Range("B16").Value = dSht.Range("U" & Rw).Value
.Range("C16").Value = dSht.Range("V" & Rw).Value
.Range("D16").Value = dSht.Range("W" & Rw).Value
.Range("E16").Value = dSht.Range("X" & Rw).Value
.Range("F16").Value = dSht.Range("Z" & Rw).Value
.Range("G16").Value = dSht.Range("AA" & Rw).Value
.Range("H16").Value = dSht.Range("AB" & Rw).Value
.Range("I16").Value = dSht.Range("AC" & Rw).Value
.Range("J16").Value = dSht.Range("AE" & Rw).Value
.Range("K16").Value = dSht.Range("AF" & Rw).Value
.Range("L16").Value = dSht.Range("AG" & Rw).Value
.Range("M16").Value = dSht.Range("AH" & Rw).Value
.Range("B20").Value = dSht.Range("AJ" & Rw).Value
.Range("C20").Value = dSht.Range("AK" & Rw).Value
.Range("D20").Value = dSht.Range("AL" & Rw).Value
.Range("E20").Value = dSht.Range("AM" & Rw).Value
.Range("F20").Value = dSht.Range("AO" & Rw).Value
.Range("G20").Value = dSht.Range("AP" & Rw).Value
.Range("H20").Value = dSht.Range("AQ" & Rw).Value
.Range("I20").Value = dSht.Range("AR" & Rw).Value
.Range("J20").Value = dSht.Range("AT" & Rw).Value
.Range("K20").Value = dSht.Range("AU" & Rw).Value
.Range("L20").Value = dSht.Range("AV" & Rw).Value
.Range("M20").Value = dSht.Range("AW" & Rw).Value
End With

If MakeBooks Then 'if making separate workbooks from filled out form
ActiveSheet.Move
ActiveWorkbook.SaveAs SavePath & Range("B3").Value, xlNormal
ActiveWorkbook.Close False
End If
Cnt = Cnt + 1
Next Rw
dSht.Activate
If MakeBooks Then
MsgBox "Workbooks created: " & Cnt
Else
MsgBox "Worksheets created: " & Cnt
End If

Application.ScreenUpdating = True
End Sub
 
Upvote 0
OK whilst that works ...well sort of as it does not copy the cell formatting over!!!!!!

The cell formatting is the bit that I need! as this contains the colours ek ... is this not possible???

Urgent help needed please

MVP's????
 
Upvote 0
The section of code you are editing has .Value all over the place, explicitly instructing to mirror the value only. Take that out to implicitly allow the entire cell(s) to be copied, formatting and all.

Also, ranges of cells that are adjacent and being copied to another range of cells that are adjacent can be copied together in a single command outlining the two ranges. This version of yours is thus shortened by merging some of those adjacent ranges together.
Rich (BB code):
Option Explicit

Sub FillOutTemplate()
'Jerry Beaucaire  4/25/2010
'From Sheet1 data fill out template on sheet2 and save
'each sheet as its own file.
Dim LastRw As Long, Rw As Long, Cnt As Long
Dim dSht As Worksheet, tSht As Worksheet
Dim MakeBooks As Boolean, SavePath As String

Application.ScreenUpdating = False  'speed up macro execution
Application.DisplayAlerts = False   'no alerts, default answers used
Set dSht = Sheets("Data")           'sheet with data on it starting in row2
Set tSht = Sheets("Template")       'sheet to copy and fill out

'Option to create separate workbooks
    MakeBooks = MsgBox("Create separate workbooks?" & vbLf & vbLf & _
        "YES = template will be copied to separate workbooks." & vbLf & _
        "NO = template will be copied to sheets within this same workbook", _
            vbYesNo + vbQuestion) = vbYes

If MakeBooks Then   'select a folder for the new workbooks
    MsgBox "Please select a destination for the new workbooks"
    Do
        With Application.FileDialog(msoFileDialogFolderPicker)
            .AllowMultiSelect = False
            .Show
            If .SelectedItems.Count > 0 Then    'a folder was chosen
                SavePath = .SelectedItems(1) & "\"
                Exit Do
            Else                                'a folder was not chosen
                If MsgBox("Do you wish to abort?", _
                    vbYesNo + vbQuestion) = vbYes Then Exit Sub
            End If
        End With
    Loop
End If
'Determine last row of data then loop through the rows one at a time
    LastRw = dSht.Range("A" & Rows.Count).End(xlUp).Row
    
    For Rw = 2 To LastRw
        tSht.Copy After:=Worksheets(Worksheets.Count)   'copy the template
        With ActiveSheet                                'fill out the form
            'edit these rows to fill out your form, add more as needed
            .Name = dSht.Range("A" & Rw)
            .Range("C2") = dSht.Range("A" & Rw)
            .Range("F2") = dSht.Range("B" & Rw)
            .Range("C6") = dSht.Range("C" & Rw)
            .Range("C5") = dSht.Range("D" & Rw)
            .Range("B12:E12") = dSht.Range("F" & Rw, "I" & Rw)
            .Range("F12:I12") = dSht.Range("K" & Rw, "N" & Rw)
            .Range("J12:M12") = dSht.Range("P" & Rw, "S" & Rw)
            .Range("B16:E16") = dSht.Range("U" & Rw, "X" & Rw)
            .Range("F16") = dSht.Range("Z" & Rw)
            .Range("G16:I16") = dSht.Range("AA" & Rw, "AC" & Rw)
            .Range("J16:M16") = dSht.Range("AE" & Rw, "AH" & Rw)
            .Range("B20:E20") = dSht.Range("AJ" & Rw, "AM" & Rw)
            .Range("F20:I20") = dSht.Range("AO" & Rw, "AR" & Rw)
            .Range("J20:M20") = dSht.Range("AT" & Rw, "AW" & Rw)
        End With
        
        If MakeBooks Then       'if making separate workbooks from filled out form
            ActiveSheet.Move
            ActiveWorkbook.SaveAs SavePath & Range("B3").Value, xlNormal
            ActiveWorkbook.Close False
        End If
        Cnt = Cnt + 1
    Next Rw
    dSht.Activate
    If MakeBooks Then
        MsgBox "Workbooks created: " & Cnt
    Else
        MsgBox "Worksheets created: " & Cnt
    End If
    
Application.ScreenUpdating = True
End Sub
 
Upvote 0
Hi Jerry

Thankyou for reply

I have just tried that with the new code but it is still avoiding the cell colour! So it copies the cells over but they remain blank

many thanks

Rameses
 
Upvote 0

Forum statistics

Threads
1,215,460
Messages
6,124,949
Members
449,198
Latest member
MhammadishaqKhan

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