Making an idiot proof one step sheet.

clubagreenie

New Member
Have data that is being extracted from another source. I need to make it usable by a variety of people (hence idiot proof) so they can just create the data and copy, than open excel and single keystroke to paste etc. as below.

User opens excel, Ctrl+Shift+R;
•Paste copied data - working.
•Deleting columns - working, could be shortened?
•Find and replace data - working, could be shortened?
•Add and format new column (F) - working, could use some improvement.
•Autofit columns - working.
•Insert formula into cells in new column (F) - problem area. Formula is =(YEAR(NOW())-YEAR(E2)), want it to paste into row (F) and as its based on data in row (E) paste to the end of the data in (E).
•Add other columns and heading - sure can be improved as using select doesn't seem to make people happy.
•Autofilter data created in (F) - working.
•Protect and save sheet - working. But would like this to save to external file in new sheet with the sheet named for that report days date. Which would be the next working day.

Code to date as follows. Many thanks in advance for any assistance given.



J


Sub ReportPrep()
'
' ReportPrep Macro
'
' Keyboard Shortcut: Ctrl+Shift+R
'
'paste - OK
ActiveSheet.Paste Destination:=Sheets("working").Range("A1")


'deleteColumns - OK
Sheets("working").Range("M:S").Delete Shift:=xlToLeft
Sheets("working").Range("K:K").Delete Shift:=xlToLeft
Sheets("working").Range("E:G").Delete Shift:=xlToLeft
Sheets("working").Range("A:B").Delete Shift:=xlToLeft


'findReplace -OK
Range("A:A").Replace What:="Hand RNS", Replacement:="Hand", LookAt:=xlPart, _
SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
ReplaceFormat:=False
Range("A:A").Replace What:="Ortho Fracture RNS", Replacement:="OrthoF", LookAt:=xlPart, _
SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
ReplaceFormat:=False
Range("A:A").Replace What:="Ortho Gen RNS", Replacement:="OrthoG", LookAt:=xlPart, _
SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
ReplaceFormat:=False


'insertAge column F - OK
Range("F:F").EntireColumn.Insert
NumberFormat = "General"

'add headings - OK (improve/del select?)
Sheets("working").Range("F1").Select
ActiveCell.FormulaR1C1 = "AGE"
Sheets("working").Range("H1").Select
ActiveCell.FormulaR1C1 = "Height"
Sheets("working").Range("I1").Select
ActiveCell.FormulaR1C1 = "Weight"
Sheets("working").Range("J1").Select
ActiveCell.FormulaR1C1 = "Consent"

'autofitColumns - OK
Worksheets("working").Columns("A:J").AutoFit



'calculateAge
'paste formula to end of data range in E
'F2 > to data range E2 to end of data in E
'Formula = "=(YEAR(NOW())-YEAR(E2))"]

'filterAge - OK
'Selection.AutoFilter
'ActiveSheet.Range("$A$1:$J$75").AutoFilter Field:=6, Criteria1:=">=3", _
'Operator:=xlAnd, Criteria2:="<=16"


'protectSheet - OK
'Sheets("working").Protect

'saveWorkbook
ActiveWorkbook.Save
 

jolivanes

Well-known Member
The deleting of the Columns can be shortened to
Code:
Sheets("Working").Range("A:B, E:G, K:K, M:S").Delete
The replacing I would do with arrays.
The advantage is that if you get more values to be changed, all you need to do is add to the arrays.
Code:
Dim oldMed, newMed, i As Long
oldMed = Array("Hand RNS", "Ortho Fracture RNS", "Ortho Gen RNS")
newMed = Array("Hand", "OrthoF", "OrthoG")
For i = LBound(oldMed) To UBound(oldMed)
Range("A:A").Replace What:=oldMed(i), Replacement:=newMed(i), LookAt:=xlPart, _
SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
ReplaceFormat:=False
Headers could be entered like this.
Code:
With Sheets("working").Range("F1")
.Value = "Age"
.Offset(, 2).Value = "Height"
.Offset(, 3).Value = "Weight"
.Offset(, 4).Value = "Consent"
End With
 

Michael M

Well-known Member
This will do the formula down col "F"

Code:
Range("F2:F" & Cells(Rows.Count, "E").End(xlUp).Row).Formula = "=(YEAR(NOW())-YEAR(E2))"
 

Some videos you may like

This Week's Hot Topics

  • Importing multiple excel files into one spreadsheet
    Hi, I'm trying to import multiple excel files (with the same format into a single spreadsheet) so that each day's file is listed underneath the...
  • find many based on a certain criteria
    good evening, I hope someone can help me? I have a workbook sheet 2 contains lots of data.... I would like to be able to find anything on sheet...
  • How to copy multiple rows using If
    Hi all, I'm very new to VBA and have written this simple code to copy certain cells if a certain cell within that row contains any data. I need...
  • VBA If statement
    Dear All, I have two dates, where I'd like a message box to pop, if the dates are between this criteria. [CODE] sDate1 = #10/1/2019#...
  • Text Format
    I have a sheet for user to keyin the data. The format of the data can be 451 / 1903, 0012 / 9908 or 00287 / 0099. The number after the "/" is...
  • Macro to copy values across rows and transposing them and add the user id
    [FONT=Times New Roman][SIZE=3][COLOR=#000000][/COLOR][/SIZE][/FONT][FONT=Calibri][SIZE=3][COLOR=#000000]Hi,[/COLOR][/SIZE][/FONT] [FONT=Times New...
Top