Create a non-contiguous range

MrPez

Board Regular
Joined
Jan 28, 2010
Messages
128
I am trying to create a range to use linest. My data is not continuous and some entries may be errors/zeros. So I need some way to interrogate the data and only include the actual numbers in the range.

For example, say my potential data is in M33:M42,M47:M52,M56:M60 but only M33,M34,M35,M47,M48 actually contain values. The rest are #DIV/0 or #VALUE! errors due to other data being missing.

Any idea how I can accomplish this?
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
For example, say my potential data is in M33:M42,M47:M52,M56:M60

Hi.

By this do you mean that there is data in M43:M46 and M53:M55 which would interfere with any attempt to reference the range M33:M60 within any formula?

Regards
 
Upvote 0
One way, assuming there are no numbers in the between cells (because the function only accepts a single-area range):


Row\Col
M​
N​
O​
P​
Q​
R​
33​
3​
2​
1​
O33:P33: {=LINEST(CloseRows(M33:M60))}
34​
5​
35​
7​
36​
#DIV/0!​
37​
#N/A​
38​
bob
39​
#DIV/0!​
40​
#N/A​
41​
bob
42​
#DIV/0!​
43​
44​
45​
46​
47​
9​
48​
11​
49​
#DIV/0!​
50​
#N/A​
51​
bob
52​
#DIV/0!​
53​
54​
55​
56​
#DIV/0!​
57​
#N/A​
58​
bob
59​
#DIV/0!​
60​
#N/A​

Code:
Function CloseRows(r As Range, _
                   Optional iMode As Long = 1) As Variant
  ' shg 2015
  ' Returns a variant array comprising the filled rows of r

  ' iMode
  '   1     keep numbers
  '   2     keep strings
  '   3     keep numbers & strings
  '   4     keep Booleans
  '   5     keep Booleans & numbers
  '   6     keep Booleans & strings
  '   7     keep everything except empty & errors

  Const iNum        As Long = 1
  Const iStr        As Long = 2
  Const iBoo        As Long = 4

  Dim av            As Variant
  Dim avOut         As Variant

  Dim iR            As Long
  Dim iW            As Long
  Dim iTop          As Long
  Dim jR            As Long
  Dim jTop          As Long

  av = r.Value2
  iTop = UBound(av, 1)
  jTop = UBound(av, 2)

  Do While iR < iTop
    iR = iR + 1
    For jR = 1 To UBound(av, 2)
      Select Case VarType(av(iR, jR))
        Case vbEmpty, vbError
          Exit For
        Case vbDouble
          If (iMode And iNum) = 0 Then Exit For
        Case vbString
          If (iMode And iStr) = 0 Then Exit For
        Case vbBoolean
          If (iMode And iBoo) = 0 Then Exit For
      End Select
    Next jR

    If jR <= jTop Then
      ' close up
      For iW = iR To iTop - 1
        For jR = 1 To UBound(av, 2)
          av(iW, jR) = av(iW + 1, jR)
        Next jR
      Next iW
      iTop = iTop - 1
      iR = iR - 1
    End If
  Loop

  ReDim avOut(1 To iTop, 1 To UBound(av, 2))
  For iR = 1 To iTop
    For jR = 1 To UBound(av, 2)
      avOut(iR, jR) = av(iR, jR)
    Next jR
  Next iR

  CloseRows = avOut
End Function
 
Upvote 0
If that's the case then you can achieve the same result using worksheet formulas alone:

=LINEST(INDEX(M:M,N(IF(1,MODE.MULT(IF(ISNUMBER(M33:M60),{1,1}*ROW(M33:M60)))))))

with CSE**.


**Array formulas are not entered in the same way as 'standard' formulas. Instead of pressing just ENTER, you first hold down CTRL and SHIFT, and only then press ENTER. If you've done it correctly, you'll notice Excel puts curly brackets {} around the formula (though do not attempt to manually insert these yourself).
 
Upvote 0
I don't understand either of your clever solutions, but that function seems to do what I want so thanks very much!
 
Upvote 0
That's clever, XOR LX.

The function was designed to accommodate a multi-column range, and return an array in which only rows with numbers straight across are preserved.
 
Upvote 0
That's clever, XOR LX.

The function was designed to accommodate a multi-column range, and return an array in which only rows with numbers straight across are preserved.

Ah, I see.

You'd just need a small adjustment for the equivalent formula set-up, e.g. for columns M and N:

=LINEST(INDEX($1:$1048576,N(IF(1,MODE.MULT(IF(ISNUMBER(M33:N60),{1,1}*ROW(M33:N60))))),N(IF(1,COLUMN(M:N)))))

Regards
 
Upvote 0
Apologies. Of course the {1,1} shouldn't be in there if we're talking more than one column.

Should be:

=LINEST(INDEX($1:$1048576,N(IF(1,MODE.MULT(IF(ISNUMBER(M33:N60),ROW(M33:N60))))),N(IF(1,COLUMN(M:N)))))

Regards
 
Upvote 0
Also very nice.

The genesis of the function was to do a surface fit f(x,y) = mx*x + my*y + mxy*x*y + b:

Row\Col
A​
B​
C​
D​
E​
1​
x
y
f(x,y)
2​
text​
0.00​
1.00​
3​
0.25​
0.00​
1.08​
4​
0.50​
#N/A​
1.15​
5​
0.75​
0.00​
#DIV/0!​
6​
#DIV/0!​
0.00​
1.30​
7​
0.00​
0.25​
#DIV/0!​
8​
0.25​
0.25​
1.01​
9​
0.50​
0.25​
1.11​
10​
0.75​
0.25​
1.22​
11​
1.00​
0.25​
#DIV/0!​
12​
0.00​
0.50​
0.80​
13​
0.25​
0.50​
text​
14​
#DIV/0!​
0.50​
1.08​
15​
0.75​
text​
text​
16​
1.00​
0.50​
1.35​
17​
#DIV/0!​
0.75​
text​
18​
#N/A​
0.75​
0.87​
19​
0.50​
0.75​
#DIV/0!​
20​
#DIV/0!​
#DIV/0!​
1.21​
21​
1.00​
0.75​
1.38​
22​
0.00​
#DIV/0!​
0.60​
23​
0.25​
1.00​
0.80​
24​
0.50​
#N/A​
#N/A​
25​
0.75​
1.00​
1.20​
26​
1.00​
#N/A​
text​
27​
28​
mx
my
mxy
b
29​
0.3​
-0.4​
0.5​
1​
A29:D29: {=LINEST(INDEX(v(CloseRows(A2:C26)),0,3), CHOOSE({3,2,1}, INDEX(v(),0,1), INDEX(v(),0,2), INDEX(v(),0,1) * INDEX(v(),0,2)), , TRUE)}
30​
1.3E-16​
1.1E-16​
2.2E-16​
6.32063E-17​
31​
1​
5.3E-17​
#N/A​
#N/A​
32​
4.3E+31​
5​
#N/A​
#N/A​
33​
0.35164​
1.4E-32​
#N/A​
#N/A​
 
Upvote 0

Forum statistics

Threads
1,214,918
Messages
6,122,257
Members
449,075
Latest member
staticfluids

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