Ever find it difficult to resize an array formula to the right size?
This is some useful VBA to help you work with array formulas on your
worksheets.  I've added this to an add-in (Technicana Utilities) and
assigned it to CTRL+SHIFT+A.  You can download a copy at
http://technicana.com/vbaSection/TechnicanaAddin.html

Public Sub SetArrayToNaturalSize()
    ' Resizes an Array formula to its 'natural size', i.e. a range
   ' big enough to display all of the array formula results

    Dim rngCurrent As Range
    Set rngCurrent = Selection

    ' Get the Contents of the Top Left Cell
   Dim vContents As Variant
    vContents = rngCurrent.Cells(1, 1).Formula

    ' Clear the current selection
   On Error GoTo FailedToClear
    ClearRange rngCurrent

    ' How big do we need to set our target range?
   Dim depth As Integer
    Dim width As Integer
    Dim vResults As Variant
    vResults = Application.Evaluate(vContents)

    ' Check the result is an array
   If Right(TypeName(vResults), 2) = "()" Then
        ' It's an array, but of how many dimensions?
       If GetArrayDimensionCount(vResults) = 2 Then
            ' 2-D Array
           depth = UBound(vResults, 1)
            width = UBound(vResults, 2)
        Else
            ' 1-D Array
           depth = 1
            width = UBound(vResults)
        End If
    Else
        ' Just a single result
       depth = 1
        width = 1
    End If

    ' Write our formula back to the Worksheet
   Range(rngCurrent.Cells(1, 1), rngCurrent.Cells(1, 1).Offset(depth -
1, width - 1)).FormulaArray = vContents

    Exit Sub

FailedToClear:
    MsgBox Title:="Failed to clear the selected range.", _
            Prompt:="This can be caused by the presence of another
array function within the bounds of the selection"
    Exit Sub

    Exit Sub
End Sub

Regards,

Chris Spicer
www.Technicana.com

--~--~---------~--~----~------------~-------~--~----~
----------------------------------------------------------------------------------
Some important links for excel users:
1. Excel and VBA Tutorials(Video and Text), Free add-ins downloads at 
http://www.excelitems.com
2. Excel tutorials at http://www.excel-macros.blogspot.com
3. Learn VBA Macros at http://www.vbamacros.blogspot.com
4. Excel Tips and Tricks at http://exceldailytip.blogspot.com
 

To post to this group, send email to excel-macros@googlegroups.com
If you find any spam message in the group, please send an email to:
Ayush Jain  @ jainayus...@gmail.com or
Ashish Jain @ 26may.1...@gmail.com
<><><><><><><><><><><><><><><><><><><><><><>
HELP US GROW !!

We reach over 5,200 subscribers worldwide and receive many nice notes about the 
learning and support from the group. Our goal is to have 10,000 subscribers by 
the end of 2009. Let friends and co-workers know they can subscribe to group at 
http://groups.google.com/group/excel-macros/subscribe
-~----------~----~----~----~------~----~------~--~---

Reply via email to