none
Pass a string or array as a parameter to a method

    Question

  • I have this statement in Excel VBA:

    Selection.Subtotal GroupBy:=2, Function:=xlSum, TotalList:=Array(5, 6, 13, _
            14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25, 26, 27, 28, 29, 30, 31, 32, 33, 34, 35, 36, 37, 38, 39, _
            40, 41, 42, 43, 44, 45, 46, 47, 48, 49, 50, 51, 52, 53, 54, 55, 56, 57, 58, 59, 60, 61, 62, 63, 64, 65, _
            66, 67, 68, 69, 70, 71, 72, 73, 74, 75, 76, 77, 78, 79, 80, 81, 82, 83, 84, 85, 86, 87, 88, 89, 90, 91, _
            92, 93, 94, 95, 96, 97, 98, 99, 100, 101, 102, 103, 104, 105, 106, 107, 108, 109, 110, 111, 112, 113_
            , 114, 115, 116, 117, 118, 119, 120, 121, 122, 123, 124, 125, 126, 127, 128, 129, 130, 131, 132, _
            133, 134, 135, 136, 137, 138, 139, 140, 141, 142, 143), Replace:=False, PageBreaks:= _
            False, SummaryBelowData:=True

     

    I would like the Array to be passed as a string or variant like this:

    Selection.Subtotal GroupBy:=1, Function:=xlSum, TotalList:=Array(aryColumns), Replace:=True, PageBreaks:= False, SummaryBelowData:=True

    Where aryColumns is an array or varColumns is a variant

    please show how to construct the array or the variant

    Wednesday, December 12, 2012 10:38 PM

Answers

  • Dim varColumns() As Variant
    Dim intMaxcolumn As Integer
    Dim intcol As Integer
    intMaxcolumn = 143
    ReDim varColumns(1 To intMaxcolumn - 7)

    'build the array of columns to be totaled
    varColumns(1) = 5
    varColumns(2) = 6
    varColumns(3) = 13

    For intcol = 14 To intMaxcolumn
        varColumns(intcol - 10) = intcol
    Next intcol

    Cells.Subtotal GroupBy:=1, Function:=xlSum, TotalList:=varColumns, Replace:=True, PageBreaks:= _
            False, SummaryBelowData:=True

    • Marked as answer by GordonGecko Thursday, December 13, 2012 5:55 PM
    Thursday, December 13, 2012 5:36 PM

All replies

  • Dim myA As Variant
    myA = Array(5, 6, 13, _
            14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25, 26, 27, 28, 29, 30, 31, 32, 33, 34, 35, 36, 37, 38, 39, _
            40, 41, 42, 43, 44, 45, 46, 47, 48, 49, 50, 51, 52, 53, 54, 55, 56, 57, 58, 59, 60, 61, 62, 63, 64, 65, _
            66, 67, 68, 69, 70, 71, 72, 73, 74, 75, 76, 77, 78, 79, 80, 81, 82, 83, 84, 85, 86, 87, 88, 89, 90, 91, _
            92, 93, 94, 95, 96, 97, 98, 99, 100, 101, 102, 103, 104, 105, 106, 107, 108, 109, 110, 111, 112, 113_
            , 114, 115, 116, 117, 118, 119, 120, 121, 122, 123, 124, 125, 126, 127, 128, 129, 130, 131, 132, _
            133, 134, 135, 136, 137, 138, 139, 140, 141, 142, 143)
        Selection.Subtotal GroupBy:=2, Function:=xlSum, TotalList:=myA, Replace:=False, PageBreaks:= _
            False, SummaryBelowData:=True
    Thursday, December 13, 2012 12:17 AM
  • Thank you , I think this is really close but not quite.  I need to build the array dynamically so I took your idea and did this:

    Dim varColumns as Variant

    'build the array of columns to be totaled
    strArray = "5, 6, 13"
    For intCol = 14 To intMaxColumn
        strArray = strArray & ", " & intCol
    Next intCol
    varColumns = Array(strArray)

    Cells.Select
        Selection.Subtotal GroupBy:=1, Function:=xlSum, TotalList:=varColumns, Replace:=True, PageBreaks:= _
            False, SummaryBelowData:=True

    I get a "Type mismatch" error when it executes the Selection statement.  I also tried:

    Selection.Subtotal GroupBy:=1, Function:=xlSum, TotalList:=Array(strArray), Replace:=True, PageBreaks:= _
            False, SummaryBelowData:=True                           

    but that got the same error

    I also tried this:

    Dim varColumns(600) as Variant

    'build the array of columns to be totaled
    varColumns(1) = 5
    varColumns(2) = 6
    varColumns(3) = 13

    For intCol = 14 To intMaxColumn
        varColumns(intCol - 10) = intCol
    Next intCol

    Cells.Select
        Selection.Subtotal GroupBy:=1, Function:=xlSum, TotalList:=varColumns, Replace:=True, PageBreaks:= _
            False, SummaryBelowData:=True

    But I got an "Application Defined or Object Defined Error" 


    Eric von Stromberg




    • Edited by GordonGecko Thursday, December 13, 2012 5:07 PM
    Thursday, December 13, 2012 3:50 PM
  • Dim varColumns() As Variant
    Dim intMaxcolumn As Integer
    Dim intcol As Integer
    intMaxcolumn = 143
    ReDim varColumns(1 To intMaxcolumn - 7)

    'build the array of columns to be totaled
    varColumns(1) = 5
    varColumns(2) = 6
    varColumns(3) = 13

    For intcol = 14 To intMaxcolumn
        varColumns(intcol - 10) = intcol
    Next intcol

    Cells.Subtotal GroupBy:=1, Function:=xlSum, TotalList:=varColumns, Replace:=True, PageBreaks:= _
            False, SummaryBelowData:=True

    • Marked as answer by GordonGecko Thursday, December 13, 2012 5:55 PM
    Thursday, December 13, 2012 5:36 PM
  • You sir, are a steely eyed missile man!!!!!

    Thank you!


    Eric von Stromberg

    Thursday, December 13, 2012 5:55 PM
  • "steely eyed missile man"

    I'll take that as a compliment ;-)

    Bernie

    Thursday, December 13, 2012 6:32 PM