Automatically hide multiple columns in one worksheet based on multiple inputs on another

AlexCross

New Member
Joined
Jun 29, 2019
Messages
4
Hello,

My employees work on multiple projects, they use excel to record their hours. We currently have 10+ projects but an employee may only be working on any 5 of those. Each employee has their own excel spreadsheet (stored on sharepoint- online 365)

I would like to be able to automatically hide columns /projects(3 columns per project) on sheet 2, that the employee is not working when the value under the Assigned heading on Sheet 1 (see C2-C13 etc) for a project is "N". Column C has a data validated function to be either "blank", "Y" or "N"

Sheet 1 below

ABCNotes:corresponding column on sheet 2 to hide
1Employee:John Smith
2Project NameAssigned
3T500Y
4T501NF-H
5T502Y
6T503NL-N
7T504Y
8T505Y
9T506NU-W
10T507NX-Z
11T508Y
12T509NAD-AF
13T510Y
14Etc

<tbody>
</tbody>

Sheet 2 below

abcdefghijklmnopqrstuvwxy
1ProjectT500 (Col:C-E)T501 (Col:f-h)T502 (Col: i - KT503 (Col: L-NT504 (Col: O-Q)T505(Col: R-T)T506 (Col: U-W)ETC
2DateStartFinishTotalStartFinishTotalStartFinishTotalStartFinishTotalStartFinishTotalStartFinishTotalStartFinishTotal
3
4
5
6
7
8

<tbody>
</tbody>


Can you please assist me with appropriate coding to complete this function, your assistance is greatly appreciated.

Alex

The result of the coding would be as follows:
abcdeijkopqrstxy
1ProjectT500 (Col:C-E)T502 (Col: i - KT504 (Col: O-Q)T505(Col: R-T)ETC
2DateStartFinishTotalStartFinishTotalStartFinishTotalStartFinishTotal
3
4
5
6
7
8

<tbody>
</tbody>
 

Some videos you may like

Excel Facts

Workdays for a market open Mon, Wed, Friday?
Yes! Use "0101011" for the weekend argument in NETWORKDAYS.INTL or WORKDAY.INTL. The 7 digits start on Monday. 1 means it is a weekend.

mumps

Well-known Member
Joined
Apr 11, 2012
Messages
8,744
Copy and paste this macro into the worksheet code module. Do the following: right click the tab name for your sheet and click 'View Code'. Paste the macro into the empty code window that opens up. Close the code window to return to your sheet. Make sure that the columns to hide have been entered in column E. Then enter an "N" in the appropriate row in column E and press the RETURN key.
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Intersect(Target, Range("C:C")) Is Nothing Then Exit Sub
    Dim splitCols As Variant
    If Target = "N" Then
        splitCols = Split(Target.Offset(0, 2), "-")
        With Sheets("Sheet2")
            .Columns.Hidden = False
            .Columns(splitCols(0) & ":" & splitCols(1)).EntireColumn.Hidden = True
        End With
    End If
End Sub
 

AlexCross

New Member
Joined
Jun 29, 2019
Messages
4
Copy and paste this macro into the worksheet code module. Do the following: right click the tab name for your sheet and click 'View Code'. Paste the macro into the empty code window that opens up. Close the code window to return to your sheet. Make sure that the columns to hide have been entered in column E. Then enter an "N" in the appropriate row in column E and press the RETURN key.
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Intersect(Target, Range("C:C")) Is Nothing Then Exit Sub
    Dim splitCols As Variant
    If Target = "N" Then
        splitCols = Split(Target.Offset(0, 2), "-")
        With Sheets("Sheet2")
            .Columns.Hidden = False
            .Columns(splitCols(0) & ":" & splitCols(1)).EntireColumn.Hidden = True
        End With
    End If
End Sub


Mumps, thanks for the quick response, I inserted code as specified in Microsoft Excel Objects/Sheet1 (Sheet1). in the Workshop panel, then saving as XLSM file. I received Run time error 9 Subscript out of range error message on the following code:

.Columns(splitCols(0) & ":" & splitCols(1)).EntireColumn.Hidden = True

I have also realised that my original message should have been more clear. If I remove the "N" from Column C / against a project, I would also like the project to reappear (ie the relevant columns become unhidden - sheet 2) PS in your notes you refer to column E... I presume this was actually column c in sheet 1 where I have place "N" against the project.

Regards Alex
 

mumps

Well-known Member
Joined
Apr 11, 2012
Messages
8,744
I tested the macro using the data you posted and it worked properly. Based on how your data was posted, it looked like column E contained the columns to hide. I think that it would be easier to help and test possible solutions if I could work with your actual file which includes any macros you are currently using. Perhaps you could upload a copy of your file to a free site such as www.box.com or www.dropbox.com. Once you do that, mark it for 'Sharing' and you will be given a link to the file that you can post here. Include a detailed explanation of what you would like to do using a few examples from your data and referring to specific cells, rows, columns and worksheets. If the workbook contains confidential information, you could replace it with generic data.
 

AlexCross

New Member
Joined
Jun 29, 2019
Messages
4
Mumps,
Got it working!!!! Didnt update column references in column E as you specified on sheet 1. Sorry

At the moment it only hides the last "N" assigned to a project - ie it can only hides one at a time and previous project hidden with "N" reappear. I was hoping to hide/ unhide multiple projects/ column when I entered an N or removed it against a project?

Appreciate your support...
 

mumps

Well-known Member
Joined
Apr 11, 2012
Messages
8,744
Try this version. Enter "N" to hide and "Y" to unhide.
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Intersect(Target, Range("C:C")) Is Nothing Then Exit Sub
    Dim splitCols As Variant
    Select Case Target.Value
        Case "N"
            splitCols = Split(Target.Offset(0, 2), "-")
            With Sheets("Sheet2")
                .Columns(splitCols(0) & ":" & splitCols(1)).EntireColumn.Hidden = True
            End With
        Case "Y"
            splitCols = Split(Target.Offset(0, 2), "-")
            With Sheets("Sheet2")
                .Columns(splitCols(0) & ":" & splitCols(1)).EntireColumn.Hidden = False
            End With
    End Select
End Sub
 

AlexCross

New Member
Joined
Jun 29, 2019
Messages
4
Try this version. Enter "N" to hide and "Y" to unhide.
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Intersect(Target, Range("C:C")) Is Nothing Then Exit Sub
    Dim splitCols As Variant
    Select Case Target.Value
        Case "N"
            splitCols = Split(Target.Offset(0, 2), "-")
            With Sheets("Sheet2")
                .Columns(splitCols(0) & ":" & splitCols(1)).EntireColumn.Hidden = True
            End With
        Case "Y"
            splitCols = Split(Target.Offset(0, 2), "-")
            With Sheets("Sheet2")
                .Columns(splitCols(0) & ":" & splitCols(1)).EntireColumn.Hidden = False
            End With
    End Select
End Sub

Mumps, that is fantastic... cannot tell you how much I appreciate your help. It is after midnight here in South Australia on Saturday night - got to work tomorrow to get job done for Monday... just taken a load off my mind with your solution. Thanks again. Alex
 

Forum statistics

Threads
1,089,443
Messages
5,408,255
Members
403,192
Latest member
hennie68

This Week's Hot Topics

  • help please
    SORRY NOT ANY GOOD AT EXCEL SO HELP WOULD BE MUCH APPRECIATED this formula is in a sheet called ignore...
  • two formulas needed
    Hello, I'll try my best to explain this: First formula needed in Sheet1 cell A2: If Sheet1 cell B2 = Sheet2 cell B2 then return a 1. If not then...
  • Dynamic Counts
    Good afternoon, we are tidying up some data & the data seems to be growing quicker than we are tidying it up! What we confirm (by reviewing it...
  • Help Excel formula eliminate duplicate values and keep only 2 identical rows.
    as picture below column A has a duplicate value. but the values are not the same as the rule. sometimes 4 rows, sometimes 10 rows or 7 or 9...
  • Macro Compile Error Sub or Function not defined
    Hello, I am trying to run macros from a validation list, all macros have been created and run perfectly on there own but I'm getting a compile...
  • Last row combined with Current Region VBA
    I'm generally happy finding the last row of data through something like Lastrow = Cells(Rows.Count, "D").End(xlUp) but I don't always receive data...
Top