Results 1 to 4 of 4

Thread: warehouse map, need to lock cell borders/colors

  1. #1

    warehouse map, need to lock cell borders/colors



    Register for a FREE account, and/
    or Log in to avoid these ads!

    Hi guys, I'm making a map of a warehouse using excel mac 2008. I made the grid into small squares, and drew the floor plan with racks/shelving and such. I used cell borders to indicate walls and aisles.

    I don't simply want to use this as a "snapshot in time" map, I want to use it as an interactive document for our inventory manager to plan out where to put boxes of our product (pallets of boxes). I would really like to program the worksheet so it locks the wall and shelving cell borders, so the user can drag our products (merged cell groups colored brown with text in them) in and out of the racks without replacing the border formatting. Is this possible? From what I know, I'm guessing there would be a VB script/formula/macro that constantly refreshes, and sets those borders every time something is dragged around. Is that correct? or is there a setting to drag and drop without overriding border formatting? any suggestions are appreciated, thanks!
    Attached Files Attached Files

  2. #2
    Administrator Ken Puls's Avatar
    Join Date
    Mar 2011
    Location
    Nanaimo, BC, Canada
    Posts
    2,294
    Articles
    57
    Blog Entries
    14
    Excel Version
    Excel Office 365 Insider
    Dragging merged cells around is going to be a problem. They're awful to work with and break.

    I'd suggest that a better way might be to program a Right Click menu and let the user select a range with the left click and drag, then right click to "create box" or something? You'd then be able to drag around boxes of "non merged" cells as a group, but would use the right click to automate construction of new ones in your format.

    Does that make sense?
    Ken Puls, FCPA, FCMA, MS MVP

    Learn to Master Your Data at the Power Query Academy (the world's most comprehensive online Power Query training), with my book M is for Data Monkey, or our new Power Query Recipe cards!

    Main Site: http://www.excelguru.ca -||- Blog: http://www.excelguru.ca/blog -||- Forums: http://www.excelguru.ca/forums
    Check out the Excelguru Facebook Fan Page -||- Follow Me on Twitter

    If you've been given VBA code (a macro) for your solution, but don't know where to put it, CLICK HERE.

  3. #3
    yes! that sounds like a great workaround.....if I had two custom menu items, "create box" and "restore shelves", the first would change the selection fill to brown and add a simple black line outside border, and then "restore shelves" would just change the selection border to a green thick line on the top and bottom, and an orange left and right side--it wouldn't touch the cell contents or the fill. Those two options would make everything work easily. ....may I ask for some code? or if it's very straightforward but tedious, could you tell me how to do it, and I can do the busy work? thank you so much

  4. #4
    Administrator Ken Puls's Avatar
    Join Date
    Mar 2011
    Location
    Nanaimo, BC, Canada
    Posts
    2,294
    Articles
    57
    Blog Entries
    14
    Excel Version
    Excel Office 365 Insider
    Okay, let's try this.

    Place the following code in the ThisWorkbook module of your file:
    Code:
    Option Explicit
    Private Sub Workbook_Activate()
    'Add custom menu items
        With Application
            .CommandBars("Cell").Reset
            With .CommandBars("Cell").Controls
                With .Add
                    .Caption = "Create Box"
                    .OnAction = ThisWorkbook.Name & "!CreateBox"
                    .Tag = "Create"
                    .BeginGroup = True
                End With
                With .Add
                    .Caption = "Restore Shelves"
                    .OnAction = ThisWorkbook.Name & "!RestoreShelves"
                    .Tag = "Restore"
                End With
            End With
        End With
    End Sub
    
    Private Sub workbook_deactivate()
    'Remove right click menu additions when workbook deactivated
        Application.CommandBars("Cell").Reset
    End Sub
    And the following code in a standard Module:
    Code:
    Option Explicit
    Private Sub CreateBox()
    'Brown fill, black border around cell
        With Selection
            'Set fill color here
            .Interior.Color = 9944516
            
            With .Borders(xlEdgeLeft)
                .LineStyle = xlContinuous
                .Weight = xlThin
            End With
            With .Borders(xlEdgeRight)
                .LineStyle = xlContinuous
                .Weight = xlThin
            End With
            With .Borders(xlEdgeTop)
                .LineStyle = xlContinuous
                .Weight = xlThin
            End With
            With .Borders(xlEdgeBottom)
                .LineStyle = xlContinuous
                .Weight = xlThin
            End With
            With .Borders(xlInsideVertical)
                .LineStyle = xlNone
            End With
            With .Borders(xlInsideHorizontal)
                .LineStyle = xlNone
            End With
        End With
    End Sub
    
    Private Sub RestoreShelves()
    'Change the selection border to a green thick line on the top and
    'bottom, and an orange left and right side
    'Won't touch the cell contents or the fill.
        With Selection
            With .Borders(xlEdgeLeft)
                .Color = 682978
                .LineStyle = xlContinuous
                .Weight = xlThick
            End With
            With .Borders(xlEdgeRight)
                .Color = 682978
                .LineStyle = xlContinuous
                .Weight = xlThick
            End With
            With .Borders(xlEdgeTop)
                .Color = -11489280
                .LineStyle = xlContinuous
                .Weight = xlThick
            End With
            With .Borders(xlEdgeBottom)
                .Color = -11489280
                .LineStyle = xlContinuous
                .Weight = xlThick
            End With
            With .Borders(xlInsideVertical)
                .LineStyle = xlNone
            End With
            With .Borders(xlInsideHorizontal)
                .LineStyle = xlNone
            End With
        End With
    End Sub
    If you need any help figuring out what goes where, this article may help.

    The save the file as an xlsm file (so that the macros stay there), close it, and reopen it. You should now have two items at the bottom of your right click menu that will (hopefully) do what you're after.

    Let me know if you need any more help with it.
    Ken Puls, FCPA, FCMA, MS MVP

    Learn to Master Your Data at the Power Query Academy (the world's most comprehensive online Power Query training), with my book M is for Data Monkey, or our new Power Query Recipe cards!

    Main Site: http://www.excelguru.ca -||- Blog: http://www.excelguru.ca/blog -||- Forums: http://www.excelguru.ca/forums
    Check out the Excelguru Facebook Fan Page -||- Follow Me on Twitter

    If you've been given VBA code (a macro) for your solution, but don't know where to put it, CLICK HERE.

Posting Permissions

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