Results 1 to 4 of 4

Thread: Making an idiot proof one step sheet.

  1. #1
    New Member
    Join Date
    Sep 2019
    Posts
    3
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Making an idiot proof one step sheet.

    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


  2. #2
    Board Regular
    Join Date
    Sep 2004
    Posts
    1,379
    Post Thanks / Like
    Mentioned
    9 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Making an idiot proof one step sheet.

    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
    Theory is when you know something, but it doesn’t work. Practice is when something works, but you don’t know why. Politicians combine theory and practice: nothing works and they don’t know why.

  3. #3
    Board Regular Michael M's Avatar
    Join Date
    Oct 2005
    Location
    South Western NSW
    Posts
    17,812
    Post Thanks / Like
    Mentioned
    18 Post(s)
    Tagged
    2 Thread(s)

    Default Re: Making an idiot proof one step sheet.

    This will do the formula down col "F"

    Code:
    Range("F2:F" & Cells(Rows.Count, "E").End(xlUp).Row).Formula = "=(YEAR(NOW())-YEAR(E2))"
    Regards
    Michael M
    ---------------------------------------
    The more I learn, the less I seem to know.....A Please and Thank You cost nothing !
    It's easier to debug if we can see the whole macro !
    Home 2007 & 2013

    - Posting guidelines, forum rules and terms of use

    - To download Mr Excel HTML Maker

    - Try searching for your answer first, see how

    - Read the FAQs

    - List of BB codes


    [CODE]Place Your Code Here[/CODE]

  4. #4
    New Member
    Join Date
    Sep 2019
    Posts
    3
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Making an idiot proof one step sheet.

    Many thanks for the assistance.

    Worked a treat to get me to my next roadblock

Some videos you may like

User Tag List

Tags for this Thread

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •