Looking for assistance using MS Excel VBA to hide rows

kcampbell675

New Member
Joined
Sep 19, 2023
Messages
5
Office Version
  1. 365
Platform
  1. Windows
Hello, I am attempting to unhide rows via Excel VBA if a particular selection is made. The workbook is intended for internal customers to complete for capital requests; thus it is form workbook. When the user selects the "Software/License" category other rows will unhide with further questions. The other caveat there are a number of rows for a category selection which may not be the "Software/License" category selected by the user. The code needs to unhide rows 14 - 17 as long as one row in col. "F" (Category) has selected "Software/ Licenses. I am having difficulty writing the code and making the correct VBA selections. The current issues I have the if I add a category selection that is not "Software/Licenses" despite having another row with the aforementioned selection, the rows re-hide. I have tried integer code unsuccessfully. I would appreciate any assistance. Thanks you! My current code is below.

Private Sub Worksheet_Change(ByVal Target As Range)
ActiveSheet.Activate
If Not Application.Intersect(Range("$f$22:$F$86"), Range(Target.Address)) Is Nothing Then
Select Case Target.Value
Case Is = "Software/License": Rows("14:19").EntireRow.Hidden = False

Case Is <> "Software/License": Rows("14:19").EntireRow.Hidden = True

End Select
End If

End Subject

CPR form Materials & Labor tab for K Campbell.xlsm
ABCDEFGHIJKLMNO
1Capital Purchase Request Form - 2024Return to CPR Form
2V1-11/03/2023
3Materials & Labor
4Project Name: ACCOUNTS RECEIVABLE AND BILLING SYSTEM
5Special Instructions and NotesCategoryExt PriceFreightTaxTotal
6Hardware -
7Software/License -
8Labor -
9Other Capital -
10Ship To Address` -
11Ship To City, State ZipDisposal -
12Ship to Contact PersonTotal----
13
14Software license capitalization criteria (all criteria below must be "Yes" to proceed as a capital request)Software license approvals
15SR ownership &/or control of software on premise or cloud selectPlease answer all 3 questions.DOA (Delegation of authority) approvalselectPlease answer.
16At least 1 year term for software license / renewalselect PRB (Project Review Board) approval number
17At least 1 year term is non-cancelableselectARB (Architecture Review Board) approval number
18
19Freight PercentSales Tax Rate
20Quote Detail0.00%0.00%
21Vendor NameQuote NumberLine #DescriptionCategoryExt PriceFreightTaxTotal
22Software/License---
23Hardware---
24---
25---
26---
27---
28---
29---
30---
31---
32---
33---
34---
Materials & Labor
Cell Formulas
RangeFormula
B1B1='https://chartercom-my.sharepoint.com/personal/ken_campbell_charter_com/Documents/Documents/Ken main/Capital Forms & Instructions/2024/[CPR Form_2024 v1 beta new working.xlsm]CPR Request Form'!$A$1
B2B2='https://chartercom-my.sharepoint.com/personal/ken_campbell_charter_com/Documents/Documents/Ken main/Capital Forms & Instructions/2024/[CPR Form_2024 v1 beta new working.xlsm]CPR Request Form'!$A$2
B3B3=MID(CELL("filename",A1),FIND("]",CELL("filename",A1))+1,255)
B4B4=IF('https://chartercom-my.sharepoint.com/personal/ken_campbell_charter_com/Documents/Documents/Ken main/Capital Forms & Instructions/2024/[CPR Form_2024 v1 beta new working.xlsm]CPR Request Form'!$C$20="select","",IF('https://chartercom-my.sharepoint.com/personal/ken_campbell_charter_com/Documents/Documents/Ken main/Capital Forms & Instructions/2024/[CPR Form_2024 v1 beta new working.xlsm]CPR Request Form'!$C$20<>"****Project not in list****",CONCATENATE("Project Name: ",'https://chartercom-my.sharepoint.com/personal/ken_campbell_charter_com/Documents/Documents/Ken main/Capital Forms & Instructions/2024/[CPR Form_2024 v1 beta new working.xlsm]CPR Request Form'!$C$20),IF('https://chartercom-my.sharepoint.com/personal/ken_campbell_charter_com/Documents/Documents/Ken main/Capital Forms & Instructions/2024/[CPR Form_2024 v1 beta new working.xlsm]CPR Request Form'!$C$20="****Project not in list****",CONCATENATE("Project Name: ",'https://chartercom-my.sharepoint.com/personal/ken_campbell_charter_com/Documents/Documents/Ken main/Capital Forms & Instructions/2024/[CPR Form_2024 v1 beta new working.xlsm]CPR Request Form'!$C$24))))
G6:G11G6=IF(OR($E$15="Please answer all 3 questions.",$E$16="Software not capitalizable.")," ",SUMIF('https://chartercom-my.sharepoint.com/personal/ken_campbell_charter_com/Documents/Documents/Ken main/Capital Forms & Instructions/2024/[CPR Form_2024 v1 beta new working.xlsm]Materials & Labor'!$F$23:$F$86,[@Category],'https://chartercom-my.sharepoint.com/personal/ken_campbell_charter_com/Documents/Documents/Ken main/Capital Forms & Instructions/2024/[CPR Form_2024 v1 beta new working.xlsm]Materials & Labor'!$G$22:$G$86))
H6:H11H6=IF(OR($E$15="Please answer all 3 questions.",$E$16="Software not capitalizable.")," ",SUMIF('https://chartercom-my.sharepoint.com/personal/ken_campbell_charter_com/Documents/Documents/Ken main/Capital Forms & Instructions/2024/[CPR Form_2024 v1 beta new working.xlsm]Materials & Labor'!$F$23:$F$86,[@Category],'https://chartercom-my.sharepoint.com/personal/ken_campbell_charter_com/Documents/Documents/Ken main/Capital Forms & Instructions/2024/[CPR Form_2024 v1 beta new working.xlsm]Materials & Labor'!$H$22:$H$86))
I6:I11I6=IF(OR($E$15="Please answer all 3 questions.",$E$16="Software not capitalizable.")," ",SUMIF('https://chartercom-my.sharepoint.com/personal/ken_campbell_charter_com/Documents/Documents/Ken main/Capital Forms & Instructions/2024/[CPR Form_2024 v1 beta new working.xlsm]Materials & Labor'!$F$23:$F$86,[@Category],'https://chartercom-my.sharepoint.com/personal/ken_campbell_charter_com/Documents/Documents/Ken main/Capital Forms & Instructions/2024/[CPR Form_2024 v1 beta new working.xlsm]Materials & Labor'!$I$22:$I$86))
J6:J11J6=SUM(Table2[@[Ext Price]:[Tax]])
G12G12=SUBTOTAL(109,[Ext Price])
H12H12=SUBTOTAL(109,[Freight])
I12I12=SUBTOTAL(109,[Tax])
J12J12=SUBTOTAL(109,[Total])
J15J15=IF($I$15="select","Please answer."," ")
E15E15=IF($D$15="select","Please answer all 3 questions.",IF($D$16="select","Please answer all 3 questions.",IF($D$17="select","Please answer all 3 questions."," ")))
E16E16=IF($D$15="No","Software not capitalizable.",IF($D$16="No","Software not capitalizable.",IF($D$17="No","Software not capitalizable."," ")))
H22:H34H22=$G22*$H$20
I22:I34I22=$G22*$I$20
J22:J34J22='Materials & Labor'!$G22+'Materials & Labor'!$H22+'Materials & Labor'!$I22
Cells with Conditional Formatting
CellConditionCell FormatStop If True
B4Cell Valuecontains ""textNO
B3Cell Valuecontains ""textNO
Cells with Data Validation
CellAllowCriteria
F22:F34List=$F$6:$F$11
H20:I20Whole numberbetween 0 and 1
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
How about this?

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    Dim rng As Range
    Dim cell As Range
    Dim hasSoftwareLicense As Boolean

    Set rng = Me.Range("F22:G86")

    If Not Intersect(Target, rng) Is Nothing Then

        hasSoftwareLicense = False

        For Each cell In rng
            If cell.Value = "Software/License" Then
                hasSoftwareLicense = True
                Exit For
            End If
        Next cell

        If hasSoftwareLicense Then
            Rows("14:19").EntireRow.Hidden = False
        Else
            Rows("14:19").EntireRow.Hidden = True
        End If
    End If
End Sub
 
Upvote 0
How about this?

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    Dim rng As Range
    Dim cell As Range
    Dim hasSoftwareLicense As Boolean

    Set rng = Me.Range("F22:G86")

    If Not Intersect(Target, rng) Is Nothing Then

        hasSoftwareLicense = False

        For Each cell In rng
            If cell.Value = "Software/License" Then
                hasSoftwareLicense = True
                Exit For
            End If
        Next cell

        If hasSoftwareLicense Then
            Rows("14:19").EntireRow.Hidden = False
        Else
            Rows("14:19").EntireRow.Hidden = True
        End If
    End If
End Sub

How about this?

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    Dim rng As Range
    Dim cell As Range
    Dim hasSoftwareLicense As Boolean

    Set rng = Me.Range("F22:G86")

    If Not Intersect(Target, rng) Is Nothing Then

        hasSoftwareLicense = False

        For Each cell In rng
            If cell.Value = "Software/License" Then
                hasSoftwareLicense = True
                Exit For
            End If
        Next cell

        If hasSoftwareLicense Then
            Rows("14:19").EntireRow.Hidden = False
        Else
            Rows("14:19").EntireRow.Hidden = True
        End If
    End If
End Sub
Hello Triple B, so far so good!!! Thank you so much!!
 
Upvote 0

Forum statistics

Threads
1,215,071
Messages
6,122,964
Members
449,094
Latest member
Anshu121

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top