ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Worksheet Functions (https://www.excelbanter.com/excel-worksheet-functions/)
-   -   Match Each Numeric occurrence and Return Individual Rows of Data (https://www.excelbanter.com/excel-worksheet-functions/50131-match-each-numeric-occurrence-return-individual-rows-data.html)

Sam via OfficeKB.com

Match Each Numeric occurrence and Return Individual Rows of Data
 
Hi All,

Match Each Numeric occurrence of ONE Criterion and Return Individual Rows of
Data (Multiple Columns):
the Numeric Criterion may only appear ONCE in a Row, if at all.

I have a Dynamic List called "History" that spans 7 Columns and many Rows on
Sheet1:
1st Column houses ID - numeric value, formatted General
2nd Column houses Date - numeric value, formatted 26/9/2005
3rd-7th Five Columns house numeric values: single/double-digit, formatted
General.

I would like a Formula to search every Row of the 3rd-7th Column of the
Dynamic List "History" for each occurrence of a particular single-digit or
double-digit numeric criterion by using an Input Cell for flexibility (so I
may specify whatever numeric criterion to match within the List).

Each matched occurrence of the specified numeric criterion should Return the
following data from its Row within the Dynamic List "History": ID, Date and
actual Numeric Value.

To summarise: whenever a match is found in a Row, 3 Cells of data (ID, Date
and Numeric Value) should be Returned to a NEW Row on Sheet2.

Thanks
Sam


--
Message posted via OfficeKB.com
http://www.officekb.com/Uwe/Forums.a...tions/200510/1

Domenic

In article <55beba6df9c83@uwe, "Sam via OfficeKB.com" <u4102@uwe
wrote:

To summarise: whenever a match is found in a Row, 3 Cells of data (ID, Date
and Numeric Value) should be Returned to a NEW Row on Sheet2.


I'm not sure what you mean by, "...and Numeric Value". Each row
contains 5 numeric values. Which one do you want? Or do you want the
total?

Sam via OfficeKB.com

Hi Domenic,

Thanks for reply.

I'm not sure what you mean by, "...and Numeric Value". Each row
contains 5 numeric values. Which one do you want? Or do you want the
total?


"...and Numeric Value"

This is the Numeric Criterion that is being matched.

Which one do you want?

The value of the individual Numeric Criterion that is being matched.

To summarise: whenever a match is found in a Row, 3 Cells of data (ID, Date
and Numeric Value) should be Returned to a NEW Row on Sheet2.


Cheers
Sam

Domenic wrote:
To summarise: whenever a match is found in a Row, 3 Cells of data (ID, Date
and Numeric Value) should be Returned to a NEW Row on Sheet2.


I'm not sure what you mean by, "...and Numeric Value". Each row
contains 5 numeric values. Which one do you want? Or do you want the
total?



--
Message posted via OfficeKB.com
http://www.officekb.com/Uwe/Forums.a...tions/200510/1

Domenic

First, define three separate dynamic ranges. One for the column
containing the ID, one for the column containing the Date, and one for
the columns containing your values (all five columns). Once you've done
that, try the following...

A1: enter your criteria/numeric value

B1:

=SUM(--(MMULT(--(Values=A1),TRANSPOSE(COLUMN(Values)^0))0))

....confirmed with CONTROL+SHIFT+ENTER

C1, copied down:

=IF(ROWS(C$1:C1)<=$B$1,INDEX(ID,SMALL(IF(MMULT(--(Values=$A$1),TRANSPOSE(
COLUMN(Values)^0)),ROW(ID)-MIN(ROW(ID))+1),ROWS(C$1:C1))),"")

....confirmed with CONTROL+SHIFT+ENTER

D1, copied down:

=IF(ROWS(D$1:D1)<=$B$1,INDEX(Date,SMALL(IF(MMULT(--(Values=$A$1),TRANSPOS
E(COLUMN(Values)^0)),ROW(Date)-MIN(ROW(Date))+1),ROWS(D$1:D1))),"")

....confirmed with CONTROL+SHIFT+ENTER.

In addition, you can also define a reference (Insert Name Define)
for this part of the formula...

MMULT(--(Values=$A$1),TRANSPOSE(COLUMN(Values)^0))

....and replace it with the name you've given it.

Hope this helps!

In article <55bf8a838b3d7@uwe, "Sam via OfficeKB.com" <u4102@uwe
wrote:

Hi Domenic,

Thanks for reply.

I'm not sure what you mean by, "...and Numeric Value". Each row
contains 5 numeric values. Which one do you want? Or do you want the
total?


"...and Numeric Value"

This is the Numeric Criterion that is being matched.

Which one do you want?

The value of the individual Numeric Criterion that is being matched.

To summarise: whenever a match is found in a Row, 3 Cells of data (ID, Date
and Numeric Value) should be Returned to a NEW Row on Sheet2.


Cheers
Sam


Sam via OfficeKB.com

Hi Domenic,

Solution is Great! Thank you very much for your time and assistance.

Cheers,
Sam

Domenic wrote:
First, define three separate dynamic ranges. One for the column
containing the ID, one for the column containing the Date, and one for
the columns containing your values (all five columns). Once you've done
that, try the following...

A1: enter your criteria/numeric value

B1:

=SUM(--(MMULT(--(Values=A1),TRANSPOSE(COLUMN(Values)^0))0))

...confirmed with CONTROL+SHIFT+ENTER

C1, copied down:

=IF(ROWS(C$1:C1)<=$B$1,INDEX(ID,SMALL(IF(MMULT(--(Values=$A$1),TRANSPOSE(
COLUMN(Values)^0)),ROW(ID)-MIN(ROW(ID))+1),ROWS(C$1:C1))),"")

...confirmed with CONTROL+SHIFT+ENTER

D1, copied down:

=IF(ROWS(D$1:D1)<=$B$1,INDEX(Date,SMALL(IF(MMUL T(--(Values=$A$1),TRANSPOS
E(COLUMN(Values)^0)),ROW(Date)-MIN(ROW(Date))+1),ROWS(D$1:D1))),"")

...confirmed with CONTROL+SHIFT+ENTER.

In addition, you can also define a reference (Insert Name Define)
for this part of the formula...

MMULT(--(Values=$A$1),TRANSPOSE(COLUMN(Values)^0))

...and replace it with the name you've given it.

Hope this helps!

Hi Domenic,

[quoted text clipped - 15 lines]
Cheers
Sam



--
Message posted via OfficeKB.com
http://www.officekb.com/Uwe/Forums.a...tions/200510/1


All times are GMT +1. The time now is 06:57 PM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
ExcelBanter.com