Last entry in a column

cidgreen

New Member
Joined
Aug 26, 2002
Messages
22
Hello,

I need to find a formula to return the last entry (which could be text or a number) in a specified column. I'm stuggling to find the solution - excel help is no good, and I can only find one website that might show me how to do it but using a load of INDIRECTs and ADDRESSes seems unnecessarily complicated.

It says:

To find the last entry in the second column of DataRange2, use the following Array Formula:

=INDIRECT(ADDRESS(MAX((DataRange2<>"")*ROW(DataRange2)),
COLUMN(DataRange2)+1,4))

So is that the only way to do it or is there a simpler way?

Thanks in advance,
Chris.
 

Excel Facts

Return population for a City
If you have a list of cities in A2:A100, use Data, Geography. Then =A2.Population and copy down.
On 2002-09-09 03:24, cidgreen wrote:
Hello,

I need to find a formula to return the last entry (which could be text or a number) in a specified column. I'm stuggling to find the solution - excel help is no good, and I can only find one website that might show me how to do it but using a load of INDIRECTs and ADDRESSes seems unnecessarily complicated.

It says:

To find the last entry in the second column of DataRange2, use the following Array Formula:

=INDIRECT(ADDRESS(MAX((DataRange2<>"")*ROW(DataRange2)),
COLUMN(DataRange2)+1,4))

So is that the only way to do it or is there a simpler way?

Thanks in advance,
Chris.

For references of numeric type:

( 1.) Activate Insert|Name|Define.
( 2.) Enter BigNum as name in the Names in Workbook box.
( 3.) Enter the following in the Refers to box:

9.99999999999999E+307

( 4.) Click OK.

If the reference of interest is of numeric type:

=MATCH(BigNum,A:A)

gives the location/position of the last cell in use in A.

=MATCH(BigNum,E2:E24)

gives the location/position of the last cell in use in E2:E24.

=LOOKUP(BigNum,A:A)

and similarly

=LOOKUP(BigNum,E2:E24)

retrieve the value in the last cell in use.

For references of "text" type, replace BigNum with REPT("z",90) in all of the formulas above.

For references of mixed type, I'd suggest using the following instead of the array-formula:

=MAX(MATCH(BigNum,A:A),MATCH(REPT("z",90),A:A))

gives the location/position of the last cell in use in A.

To get the last value from a reference of mixed type, use:

=INDIRECT(ADDRESS(MAX(MATCH(BigNum,A:A),MATCH(REPT("z",90),A:A)),1))

or

=OFFSET(A1,MAX(MATCH(7000,A:A),MATCH(REPT("z",90),A:A))-1,0,1,1)

Aladin
This message was edited by aladin akyurek on 2002-09-09 04:24
 
Upvote 0

Forum statistics

Threads
1,223,579
Messages
6,173,171
Members
452,504
Latest member
frankkeith2233

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