UDF array function with two columns not next to eachother?

VBE313

Well-known Member
Joined
Mar 22, 2019
Messages
686
Office Version
  1. 365
Platform
  1. Windows
In the following function, I want to get every column that says "Y" and sum everything until the next "Y". My function works properly. However, What if column B was not next to column A? How can I get the range with two columns that are not connected?
Snag_1a4069a8.png


VBA Code:
Function getY(rng As Range)
    Dim i As Integer, j As Integer, n As Integer
    Dim temp As Integer, A(), ret()
    n = rng.Rows.Count
    ReDim ret(1 To n, 0)
    A = rng
    For j = 1 To n
        If A(j, 2) = "Y" Then
            ret(j, 0) = A(j, 1)
            i = 0
        Else
            i = i + 1
            ret(j - i, 0) = ret(j - i, 0) + A(j, 1)
        End If
    Next j
    getY = ret
End Function

Here is an example of what I need to accomplish (i know this doesn't work)
Snag_1a418d0a.png
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
How about
VBA Code:
Function getY(Rng1 As Range, Rng2 As Range) As Variant
    Dim i As Integer, j As Integer, n As Integer
    Dim A As Variant, B As Variant, ret()
    n = Rng1.Rows.Count
    ReDim ret(1 To n, 0)
    A = Rng1.Value2
    B = Rng2.Value2
    For j = 1 To n
        If B(j, 2) = "Y" Then
            ret(j, 0) = A(j, 1)
            i = 0
        Else
            i = i + 1
            ret(j - i, 0) = ret(j - i, 0) + A(j, 1)
        End If
    Next j
    getY = ret
End Function
 
Upvote 0
How about
VBA Code:
Function getY(Rng1 As Range, Rng2 As Range) As Variant
    Dim i As Integer, j As Integer, n As Integer
    Dim A As Variant, B As Variant, ret()
    n = Rng1.Rows.Count
    ReDim ret(1 To n, 0)
    A = Rng1.Value2
    B = Rng2.Value2
    For j = 1 To n
        If B(j, 2) = "Y" Then
            ret(j, 0) = A(j, 1)
            i = 0
        Else
            i = i + 1
            ret(j - i, 0) = ret(j - i, 0) + A(j, 1)
        End If
    Next j
    getY = ret
End Function
Hi Fluff, I am getting a #VALUE! when trying. I entered "=getY(A1:A33,C1:C33)" Am i typing that in wrong?
 
Upvote 0
Oops, should be
VBA Code:
If B(j, 1) = "Y" Then
 
Upvote 0
You're welcome & thanks for the feedback
 
Upvote 0

Forum statistics

Threads
1,215,461
Messages
6,124,954
Members
449,198
Latest member
MhammadishaqKhan

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