+ Reply to Thread
Results 1 to 12 of 12

Prevent user from running private macros

  1. #1
    Registered User
    Join Date
    02-01-2014
    Location
    Norway
    MS-Off Ver
    Excel 2010
    Posts
    13

    Post Prevent user from running private macros

    Hi,

    I have a workbook with several sheets and a lot of macros.

    I have protected the VBA project and also the sheets and all the macros are private.

    What I'm wondering is if there's a way to prevent users from unintentionally run macros
    from the macro menu (Alt + F8). I know that if the macros are private they wil not show
    in this menu, but if a macro is named "A" and someone type "A" in the macro meny they will be able to run it.

    I need macros to be run on the right sheet only, else it can delete other codes on the sheet.

    Hope someone can help me out here


    Thomas
    Last edited by trimmjens; 11-26-2014 at 06:14 PM.

  2. #2
    Forum Expert
    Join Date
    12-15-2009
    Location
    Chicago, IL
    MS-Off Ver
    Microsoft Office 365
    Posts
    3,177

    Re: Prevent user from running private macros

    Don't believe it is possible. The only thing i can think of is have an Event Procedure to disable any macro ran.

  3. #3
    Forum Expert
    Join Date
    01-23-2013
    Location
    USA
    MS-Off Ver
    Microsoft 365 aka Office 365
    Posts
    3,863

    Re: Prevent user from running private macros

    Hi trimmjens,

    There are a couple of tricks you can use:
    Please Login or Register  to view this content.
    In the above code, only ABC shows up in the list when your type ALT F8. Private Subs are not displayed. Subs with formal parameters (i.e. idummy - even though it is not used for anything) are not displayed. Functions are not displayed. You can rename a Sub into a function, and it will work exactly the same.

    Lewis

    Correction:
    After re-reading your original question, the only construction that may provide a solution is GHI(). You can attempt to run GHI(), but get an 'argument not optional error.
    Last edited by LJMetzger; 11-26-2014 at 03:26 PM. Reason: added correction at bottom

  4. #4
    Registered User
    Join Date
    02-01-2014
    Location
    Norway
    MS-Off Ver
    Excel 2010
    Posts
    13

    Re: Prevent user from running private macros

    Thanks for your quick reply JieJenn!

    I was afraid so. Have googled a lot without finding any answers.

    Guess I'll just gamble on that no one ever try to type anything in that macro name field and
    happen to type the right macor name.


    Thomas

  5. #5
    Registered User
    Join Date
    02-01-2014
    Location
    Norway
    MS-Off Ver
    Excel 2010
    Posts
    13

    Re: Prevent user from running private macros

    Allright, thanks.

    I'll try and see what I can make out of it.

  6. #6
    Registered User
    Join Date
    02-01-2014
    Location
    Norway
    MS-Off Ver
    Excel 2010
    Posts
    13

    Re: Prevent user from running private macros

    LJMetzger

    It was working as you said, the only problem is that when the macro is intended to run (when user presses commandbutton on sheets)
    it won't run.

    I can't see to find a way around this.


    Thomas

  7. #7
    Forum Expert mikerickson's Avatar
    Join Date
    03-30-2007
    Location
    Davis CA
    MS-Off Ver
    Excel 2011
    Posts
    6,229

    Re: Prevent user from running private macros

    Quote Originally Posted by trimmjens View Post
    Hi,

    I need macros to be run on the right sheet only, else it can delete other codes on the sheet.
    If the macros that you write must be run on a particular sheet, then specify that sheet in the code so it will only run on the good sheet. Never use ActiveSheet (unless you want the user to be able to control which sheet is effected by the macro). If some macros can be run on most sheets, but not all, code to test if the bad sheets will be effected and end the sub if they are.

    1) Use code names rather than tab names.
    2) Specify the heck out of your code.
    _
    ...How to Cross-post politely...
    ..Wrap code by selecting the code and clicking the # or read this. Thank you.

  8. #8
    Registered User
    Join Date
    02-01-2014
    Location
    Norway
    MS-Off Ver
    Excel 2010
    Posts
    13

    Re: Prevent user from running private macros

    Quote Originally Posted by mikerickson View Post
    If the macros that you write must be run on a particular sheet, then specify that sheet in the code so it will only run on the good sheet. Never use ActiveSheet (unless you want the user to be able to control which sheet is effected by the macro). If some macros can be run on most sheets, but not all, code to test if the bad sheets will be effected and end the sub if they are.

    1) Use code names rather than tab names.
    2) Specify the heck out of your code.
    I have done that on one of the codes.

    Please Login or Register  to view this content.
    It is a solution for it, but I hoped it was one easy way to do it for all subs instead of specifying it for each one.

    Thanks anyway!

  9. #9
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    44,464

    Re: Prevent user from running private macros

    If your macros are all internal and private, then no-one needs to know what they are called.

    I generally prefix my subroutines with an "s" and give a descriptive name. So, I might have
    Please Login or Register  to view this content.
    Now, if anyone can accidentally type that without knowing it's there, I'd be amazed. If you have a "main" subroutine that calls other subroutines and functions, you could make the name of the main routine very obtuse so that no-one can/will type it by accident, and you could set a global boolean variable to indicate that the main routine is being executed. All the other routines could check if that boolean variable is set to true and exit if it isn't.

    And, has been said, if a routine has a dependency on a specific worksheet, ensure that the code relates only to that worksheet. Note that the worksheet does not have to be active/selected, just that all references are fully qualified.

    Regards, TMS
    Trevor Shuttleworth - Retired Excel/VBA Consultant

    I dream of a better world where chickens can cross the road without having their motives questioned

    'Being unapologetic means never having to say you're sorry' John Cooper Clarke


  10. #10
    Forum Expert
    Join Date
    01-23-2013
    Location
    USA
    MS-Off Ver
    Microsoft 365 aka Office 365
    Posts
    3,863

    Re: Prevent user from running private macros

    If you are using Shapes and/or Forms Controls for CommandButtons, you can use Application.Caller to determine if the routine execution was started by Control (will generate the caller name) or by being called from the Macro Menu or from another routine (will generate text 'Error 2023' in Excel 2003).

    I don't know of a similar mechanism for 'Active X' controls.

    Lewis

  11. #11
    Registered User
    Join Date
    02-01-2014
    Location
    Norway
    MS-Off Ver
    Excel 2010
    Posts
    13

    Re: Prevent user from running private macros

    Now, if anyone can accidentally type that without knowing it's there, I'd be amazed.
    Laughed a bit of that one. Hehe It's true, I guess no one will ever manage to do that. It's only that my workbook has potentially many users
    and I just wanted to make it bulletproof.

    But as you say... To guess a macro name is almost the same as guessing a password.

  12. #12
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    44,464

    Re: Prevent user from running private macros

    To guess a macro name is almost the same as guessing a password.
    Yep. And, the longer and more descriptive you make it, the less chance there is that it can be guessed or typed by accident.

    Please Login or Register  to view this content.
    I know that's a bit over the top ... don't think I actually do that ... but you get the drift. No way can you guess it ... or type it accidentally.

    If it's called from a main subroutine, a button or a shape, you could pass it a parameter ... useful or not.

    Please Login or Register  to view this content.
    I believe that you can actually call a subroutine AND pass it a parameter in the Macro Dialogue Box ... but I'd be impressed if anyone did.

    Nothing is bulletproof ... but you can make it pretty secure. Just don't call your subroutines A, B, C, etc., no matter how convenient.

    Regards, TMS



    If you are satisfied with the solution(s) provided, please mark your thread as Solved.


    New quick method:
    Select Thread Tools-> Mark thread as Solved. To undo, select Thread Tools-> Mark thread as Unsolved.

    Or you can use this way:

    How to mark a thread Solved
    Go to the first post
    Click edit
    Click Go Advanced
    Just below the word Title you will see a dropdown with the word No prefix.
    Change to Solved
    Click Save


    You may also want to consider thanking those people who helped you by clicking on the little star at the bottom left of their reply to your question.

+ 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. Prevent macros running after message box show
    By herukuncahyono in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 07-15-2013, 01:09 AM
  2. Prevent two macros from running at the same time
    By Kreef in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 08-31-2011, 10:36 PM
  3. Prevent private sub macro from running
    By jman0707 in forum Excel Programming / VBA / Macros
    Replies: 6
    Last Post: 11-15-2008, 01:35 AM
  4. Prevent a user from running a macro
    By vbace2 in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 11-27-2006, 11:28 PM
  5. [SOLVED] Prevent others from running my macros
    By Frederick Chow in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 12-13-2005, 02:10 PM

Tags for this Thread

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