Home |
Search |
Today's Posts |
|
#1
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
I have a column that contains empty cells and text. I want to return the row
reference of the cells that contain text. For example€¦ A2 = empty cell A3 = empty cell A4 = 2L A5 = empty cell A6 = 2W A7 = empty cell A8 = 2L2W A9 = empty cell A10 = empty cell A11 = 2L2W A12 = empty cell The formula would return 4. Thanks to Luke I have€¦ {=MIN(IF(ISTEXT(A1:A12),ROW(A1:A12),FALSE))} However I need to copy this formula down a column. The formula should return 4 then 6 then 8 then 11 etc. The blank cells are randomly placed. I cant sort the data as I have other equations in the sheet. To add to this problem I need to repeat the row number if the original cell contains 4 or more characters. So the formula should return 4 then 6 then 8 then 8 then 11 then 11 etc. Thanks for your help. |
#2
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
On Thu, 26 Feb 2009 12:07:02 -0800, M wrote:
I have a column that contains empty cells and text. I want to return the row reference of the cells that contain text. For example… A2 = empty cell A3 = empty cell A4 = 2L A5 = empty cell A6 = 2W A7 = empty cell A8 = 2L2W A9 = empty cell A10 = empty cell A11 = 2L2W A12 = empty cell The formula would return 4. Thanks to Luke I have… {=MIN(IF(ISTEXT(A1:A12),ROW(A1:A12),FALSE))} However I need to copy this formula down a column. The formula should return 4 then 6 then 8 then 11 etc. The blank cells are randomly placed. I can’t sort the data as I have other equations in the sheet. To add to this problem I need to repeat the row number if the original cell contains 4 or more characters. So the formula should return 4 then 6 then 8 then 8 then 11 then 11 etc. Thanks for your help. Here's one way. This formula must be **array-entered** in some row. Then fill down until you start getting blanks. "rng" refers to the range of interest. If you are using a version of Excel prior to Excel 2007, rng cannot be an entire column (but could be $A$1:$A$65535) =IF(ISERR(ADDRESS(LARGE(ISTEXT(rng)*ROW(rng), COUNTA(rng)+1-ROWS($1:1)),1,4)),"",ADDRESS(LARGE( ISTEXT(rng)*ROW(rng),COUNTA(rng)+1-ROWS($1:1)),1,4)) To **array-enter** a formula, after entering the formula into the cell or formula bar, hold down <ctrl<shift while hitting <enter. If you did this correctly, Excel will place braces {...} around the formula. Then Fill Down until you start getting blanks. --ron |
#3
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Assume you want the results starting in cell C1.
Try this array formula** entered in C1 and copied down until you get blanks: =IF(ROWS(C$1:C1)<=COUNTIF(A$1:A$12,"*"),SMALL(IF(I STEXT(A$1:A$12),ROW(A$1:A$12)),ROWS(C$1:C1)),"") This assumes your *REAL* data range does in fact start on row 1. If it doesn't start on row 1 then we'll need to make a slight adjustment. ** array formulas need to be entered using the key combination of CTRL,SHIFT,ENTER (not just ENTER). Hold down both the CTRL key and the SHIFT key then hit ENTER. As for your "complication", I don't think that can be done with a single formula. If it can I'd love to see it! -- Biff Microsoft Excel MVP "M" wrote: I have a column that contains empty cells and text. I want to return the row reference of the cells that contain text. For example€¦ A2 = empty cell A3 = empty cell A4 = 2L A5 = empty cell A6 = 2W A7 = empty cell A8 = 2L2W A9 = empty cell A10 = empty cell A11 = 2L2W A12 = empty cell The formula would return 4. Thanks to Luke I have€¦ {=MIN(IF(ISTEXT(A1:A12),ROW(A1:A12),FALSE))} However I need to copy this formula down a column. The formula should return 4 then 6 then 8 then 11 etc. The blank cells are randomly placed. I cant sort the data as I have other equations in the sheet. To add to this problem I need to repeat the row number if the original cell contains 4 or more characters. So the formula should return 4 then 6 then 8 then 8 then 11 then 11 etc. Thanks for your help. |
#4
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Biff,
Just curious but what are you testing for in the first part of your formula, =IF(ROWS(C$1:C1)<=COUNTIF(A$1:A$12,"*"), why not just =SMALL(IF(ISTEXT(A$1:A$12),ROW(A$1:A$12)),ROWS(C$1 :C1)) what am I missing? Mike "T. Valko" wrote: Assume you want the results starting in cell C1. Try this array formula** entered in C1 and copied down until you get blanks: =IF(ROWS(C$1:C1)<=COUNTIF(A$1:A$12,"*"),SMALL(IF(I STEXT(A$1:A$12),ROW(A$1:A$12)),ROWS(C$1:C1)),"") This assumes your *REAL* data range does in fact start on row 1. If it doesn't start on row 1 then we'll need to make a slight adjustment. ** array formulas need to be entered using the key combination of CTRL,SHIFT,ENTER (not just ENTER). Hold down both the CTRL key and the SHIFT key then hit ENTER. As for your "complication", I don't think that can be done with a single formula. If it can I'd love to see it! -- Biff Microsoft Excel MVP "M" wrote: I have a column that contains empty cells and text. I want to return the row reference of the cells that contain text. For example€¦ A2 = empty cell A3 = empty cell A4 = 2L A5 = empty cell A6 = 2W A7 = empty cell A8 = 2L2W A9 = empty cell A10 = empty cell A11 = 2L2W A12 = empty cell The formula would return 4. Thanks to Luke I have€¦ {=MIN(IF(ISTEXT(A1:A12),ROW(A1:A12),FALSE))} However I need to copy this formula down a column. The formula should return 4 then 6 then 8 then 11 etc. The blank cells are randomly placed. I cant sort the data as I have other equations in the sheet. To add to this problem I need to repeat the row number if the original cell contains 4 or more characters. So the formula should return 4 then 6 then 8 then 8 then 11 then 11 etc. Thanks for your help. |
#5
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
=IF(ROWS(C$1:C1)<=COUNTIF(A$1:A$12,"*"),
That's an error trap. It's more efficient than: =IF(ISERROR(SMALL(IF(ISTEXT(A$1:A$12),ROW(A$1:A$12 )),ROWS(C$1:C1))), COUNTIF(A$1:A$12,"*") Returns the total number of *text* entries in the range and compares that number to number of rows the formula is copied to: =IF(ROWS(C$1:C1)<=COUNTIF(A$1:A$12,"*"), If the number of rows the formula is copied to is greater than the total number of text entries in the range then the formula returns a blank (""). Otherwise, SMALL(...,n) would return a #NUM! error. -- Biff Microsoft Excel MVP "Mike H" wrote: Biff, Just curious but what are you testing for in the first part of your formula, =IF(ROWS(C$1:C1)<=COUNTIF(A$1:A$12,"*"), why not just =SMALL(IF(ISTEXT(A$1:A$12),ROW(A$1:A$12)),ROWS(C$1 :C1)) what am I missing? Mike "T. Valko" wrote: Assume you want the results starting in cell C1. Try this array formula** entered in C1 and copied down until you get blanks: =IF(ROWS(C$1:C1)<=COUNTIF(A$1:A$12,"*"),SMALL(IF(I STEXT(A$1:A$12),ROW(A$1:A$12)),ROWS(C$1:C1)),"") This assumes your *REAL* data range does in fact start on row 1. If it doesn't start on row 1 then we'll need to make a slight adjustment. ** array formulas need to be entered using the key combination of CTRL,SHIFT,ENTER (not just ENTER). Hold down both the CTRL key and the SHIFT key then hit ENTER. As for your "complication", I don't think that can be done with a single formula. If it can I'd love to see it! -- Biff Microsoft Excel MVP "M" wrote: I have a column that contains empty cells and text. I want to return the row reference of the cells that contain text. For example€¦ A2 = empty cell A3 = empty cell A4 = 2L A5 = empty cell A6 = 2W A7 = empty cell A8 = 2L2W A9 = empty cell A10 = empty cell A11 = 2L2W A12 = empty cell The formula would return 4. Thanks to Luke I have€¦ {=MIN(IF(ISTEXT(A1:A12),ROW(A1:A12),FALSE))} However I need to copy this formula down a column. The formula should return 4 then 6 then 8 then 11 etc. The blank cells are randomly placed. I cant sort the data as I have other equations in the sheet. To add to this problem I need to repeat the row number if the original cell contains 4 or more characters. So the formula should return 4 then 6 then 8 then 8 then 11 then 11 etc. Thanks for your help. |
#6
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Ah i see, I was happy to produce NUM errors with my formula when the matches
ran out but see this is tidier. Thank you. Mike "T. Valko" wrote: =IF(ROWS(C$1:C1)<=COUNTIF(A$1:A$12,"*"), That's an error trap. It's more efficient than: =IF(ISERROR(SMALL(IF(ISTEXT(A$1:A$12),ROW(A$1:A$12 )),ROWS(C$1:C1))), COUNTIF(A$1:A$12,"*") Returns the total number of *text* entries in the range and compares that number to number of rows the formula is copied to: =IF(ROWS(C$1:C1)<=COUNTIF(A$1:A$12,"*"), If the number of rows the formula is copied to is greater than the total number of text entries in the range then the formula returns a blank (""). Otherwise, SMALL(...,n) would return a #NUM! error. -- Biff Microsoft Excel MVP "Mike H" wrote: Biff, Just curious but what are you testing for in the first part of your formula, =IF(ROWS(C$1:C1)<=COUNTIF(A$1:A$12,"*"), why not just =SMALL(IF(ISTEXT(A$1:A$12),ROW(A$1:A$12)),ROWS(C$1 :C1)) what am I missing? Mike "T. Valko" wrote: Assume you want the results starting in cell C1. Try this array formula** entered in C1 and copied down until you get blanks: =IF(ROWS(C$1:C1)<=COUNTIF(A$1:A$12,"*"),SMALL(IF(I STEXT(A$1:A$12),ROW(A$1:A$12)),ROWS(C$1:C1)),"") This assumes your *REAL* data range does in fact start on row 1. If it doesn't start on row 1 then we'll need to make a slight adjustment. ** array formulas need to be entered using the key combination of CTRL,SHIFT,ENTER (not just ENTER). Hold down both the CTRL key and the SHIFT key then hit ENTER. As for your "complication", I don't think that can be done with a single formula. If it can I'd love to see it! -- Biff Microsoft Excel MVP "M" wrote: I have a column that contains empty cells and text. I want to return the row reference of the cells that contain text. For example€¦ A2 = empty cell A3 = empty cell A4 = 2L A5 = empty cell A6 = 2W A7 = empty cell A8 = 2L2W A9 = empty cell A10 = empty cell A11 = 2L2W A12 = empty cell The formula would return 4. Thanks to Luke I have€¦ {=MIN(IF(ISTEXT(A1:A12),ROW(A1:A12),FALSE))} However I need to copy this formula down a column. The formula should return 4 then 6 then 8 then 11 etc. The blank cells are randomly placed. I cant sort the data as I have other equations in the sheet. To add to this problem I need to repeat the row number if the original cell contains 4 or more characters. So the formula should return 4 then 6 then 8 then 8 then 11 then 11 etc. Thanks for your help. |
#7
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
You're welcome!
-- Biff Microsoft Excel MVP "Mike H" wrote: Ah i see, I was happy to produce NUM errors with my formula when the matches ran out but see this is tidier. Thank you. Mike "T. Valko" wrote: =IF(ROWS(C$1:C1)<=COUNTIF(A$1:A$12,"*"), That's an error trap. It's more efficient than: =IF(ISERROR(SMALL(IF(ISTEXT(A$1:A$12),ROW(A$1:A$12 )),ROWS(C$1:C1))), COUNTIF(A$1:A$12,"*") Returns the total number of *text* entries in the range and compares that number to number of rows the formula is copied to: =IF(ROWS(C$1:C1)<=COUNTIF(A$1:A$12,"*"), If the number of rows the formula is copied to is greater than the total number of text entries in the range then the formula returns a blank (""). Otherwise, SMALL(...,n) would return a #NUM! error. -- Biff Microsoft Excel MVP "Mike H" wrote: Biff, Just curious but what are you testing for in the first part of your formula, =IF(ROWS(C$1:C1)<=COUNTIF(A$1:A$12,"*"), why not just =SMALL(IF(ISTEXT(A$1:A$12),ROW(A$1:A$12)),ROWS(C$1 :C1)) what am I missing? Mike "T. Valko" wrote: Assume you want the results starting in cell C1. Try this array formula** entered in C1 and copied down until you get blanks: =IF(ROWS(C$1:C1)<=COUNTIF(A$1:A$12,"*"),SMALL(IF(I STEXT(A$1:A$12),ROW(A$1:A$12)),ROWS(C$1:C1)),"") This assumes your *REAL* data range does in fact start on row 1. If it doesn't start on row 1 then we'll need to make a slight adjustment. ** array formulas need to be entered using the key combination of CTRL,SHIFT,ENTER (not just ENTER). Hold down both the CTRL key and the SHIFT key then hit ENTER. As for your "complication", I don't think that can be done with a single formula. If it can I'd love to see it! -- Biff Microsoft Excel MVP "M" wrote: I have a column that contains empty cells and text. I want to return the row reference of the cells that contain text. For example€¦ A2 = empty cell A3 = empty cell A4 = 2L A5 = empty cell A6 = 2W A7 = empty cell A8 = 2L2W A9 = empty cell A10 = empty cell A11 = 2L2W A12 = empty cell The formula would return 4. Thanks to Luke I have€¦ {=MIN(IF(ISTEXT(A1:A12),ROW(A1:A12),FALSE))} However I need to copy this formula down a column. The formula should return 4 then 6 then 8 then 11 etc. The blank cells are randomly placed. I cant sort the data as I have other equations in the sheet. To add to this problem I need to repeat the row number if the original cell contains 4 or more characters. So the formula should return 4 then 6 then 8 then 8 then 11 then 11 etc. Thanks for your help. |
#8
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
On Thu, 26 Feb 2009 12:07:02 -0800, M wrote:
I have a column that contains empty cells and text. I want to return the row reference of the cells that contain text. For example… A2 = empty cell A3 = empty cell A4 = 2L A5 = empty cell A6 = 2W A7 = empty cell A8 = 2L2W A9 = empty cell A10 = empty cell A11 = 2L2W A12 = empty cell The formula would return 4. Thanks to Luke I have… {=MIN(IF(ISTEXT(A1:A12),ROW(A1:A12),FALSE))} However I need to copy this formula down a column. The formula should return 4 then 6 then 8 then 11 etc. The blank cells are randomly placed. I can’t sort the data as I have other equations in the sheet. To add to this problem I need to repeat the row number if the original cell contains 4 or more characters. So the formula should return 4 then 6 then 8 then 8 then 11 then 11 etc. Thanks for your help. I already posted a formula solution to your first problem. For your complication, it is easiest done using a VBA solution. To enter this Macro (Sub), <alt-F11 opens the Visual Basic Editor. Ensure your project is highlighted in the Project Explorer window. Then, from the top menu, select Insert/Module and paste the code below into the window that opens. To use this Macro (Sub), <alt-F8 opens the macro dialog box. Select the macro by name, and <RUN. ===================================== Option Explicit Sub TextAdr() Dim c As Range Dim rSrc As Range Dim rDest As Range Dim i As Long Dim lNumEntries As Long Dim lNumResults As Long Set rSrc = Range("RNG") lNumEntries = Application.WorksheetFunction.CountA(rSrc) Set rDest = Range("C1") lNumResults = lNumEntries For Each c In rSrc If Len(c.Value) = 4 Then lNumResults = lNumResults + 1 End If Next c 'clear destination cells +1 Range(rDest, rDest.Offset(lNumResults, 0)).ClearContents 'get addresses i = 0 For Each c In rSrc Select Case Len(c.Value) Case Is = 4 rDest.Offset(i, 0).Value = c.Address rDest.Offset(i + 1, 0).Value = c.Address i = i + 2 Case Is 1 rDest.Offset(i, 0).Value = c.Address i = i + 1 End Select Next c End Sub =================================== --ron |
#9
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Hi,
Put his formula in any cell (except row 1). Drag down and it will return the row numbers of columnA that have text. It will start producing #NUM errors when it stops finding text in the range =SMALL(IF(ISTEXT($A$1:$A$12),ROW($A$1:$A$12)),ROW( )-ROW($D$1)) 'This is an array formula which must be entered with CTRL+Shift+Enter and NOT 'just enter. If you do it correctly then Excel will put curly brackets around 'the formula{}. You can't type these yourself. If you Edit the ranges 'then you must re-enter as An array Mike "M" wrote: I have a column that contains empty cells and text. I want to return the row reference of the cells that contain text. For example€¦ A2 = empty cell A3 = empty cell A4 = 2L A5 = empty cell A6 = 2W A7 = empty cell A8 = 2L2W A9 = empty cell A10 = empty cell A11 = 2L2W A12 = empty cell The formula would return 4. Thanks to Luke I have€¦ {=MIN(IF(ISTEXT(A1:A12),ROW(A1:A12),FALSE))} However I need to copy this formula down a column. The formula should return 4 then 6 then 8 then 11 etc. The blank cells are randomly placed. I cant sort the data as I have other equations in the sheet. To add to this problem I need to repeat the row number if the original cell contains 4 or more characters. So the formula should return 4 then 6 then 8 then 8 then 11 then 11 etc. Thanks for your help. |
#10
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Jst realised my formula is over complicated,
Try this array entered =SMALL(IF(ISTEXT($A$1:$A$12),ROW($A$1:$A$12)),ROW( )) Mike "Mike H" wrote: Hi, Put his formula in any cell (except row 1). Drag down and it will return the row numbers of columnA that have text. It will start producing #NUM errors when it stops finding text in the range =SMALL(IF(ISTEXT($A$1:$A$12),ROW($A$1:$A$12)),ROW( )-ROW($D$1)) 'This is an array formula which must be entered with CTRL+Shift+Enter and NOT 'just enter. If you do it correctly then Excel will put curly brackets around 'the formula{}. You can't type these yourself. If you Edit the ranges 'then you must re-enter as An array Mike "M" wrote: I have a column that contains empty cells and text. I want to return the row reference of the cells that contain text. For example€¦ A2 = empty cell A3 = empty cell A4 = 2L A5 = empty cell A6 = 2W A7 = empty cell A8 = 2L2W A9 = empty cell A10 = empty cell A11 = 2L2W A12 = empty cell The formula would return 4. Thanks to Luke I have€¦ {=MIN(IF(ISTEXT(A1:A12),ROW(A1:A12),FALSE))} However I need to copy this formula down a column. The formula should return 4 then 6 then 8 then 11 etc. The blank cells are randomly placed. I cant sort the data as I have other equations in the sheet. To add to this problem I need to repeat the row number if the original cell contains 4 or more characters. So the formula should return 4 then 6 then 8 then 8 then 11 then 11 etc. Thanks for your help. |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
How can I use Text to wipe out subsequent dates? | Excel Discussion (Misc queries) | |||
Formula that will change subsequent cells in a column to match fir | Excel Discussion (Misc queries) | |||
Elimnating subsequent cells | Excel Discussion (Misc queries) | |||
how do I keep column titles on subsequent pages of a pivot table | Excel Worksheet Functions | |||
Tool fro entering data in subsequent cells | Excel Discussion (Misc queries) |