Extract all cells from a column that meet criteria

yaniv_sa

New Member
Joined
Nov 4, 2018
Messages
7
Hey,
I have a colum A (in sheet '2174') that have this kind of data:

1335001410
1335003990
1341000930
1341001790
1341001930
1341001990
1341002930
1341002990
1341003930
1841060182
1841060471
1842200760
1842201840
1842202841
1842203840
1842203841
1842205840
1842206840
1842207810

<colgroup><col></colgroup><tbody>
</tbody>

i want to extract only number that meet this crateria to the main sheet (colum A):
if > 1600000000 and last 3 digits 930 or <1600000000 and last 3 digits are 840.
with out VBA

the result should be like this:
1341000930
1341001930
1341002930
1341003930
1842201840
1842203840
1842205840
1842206840

<colgroup><col></colgroup><tbody>
</tbody>

I have tried may options with match and index but couldn't get it right.

please help.
 

Excel Facts

What did Pito Salas invent?
Pito Salas, working for Lotus, popularized what would become to be pivot tables. It was released as Lotus Improv in 1989.
Hi

Your results don't comply with your criteria.
Example: 1341000930
Is >
1600000000 but the last 3 digits are NOT 930.

 
Upvote 0
Okay. I also made a mistake.
Let me show you in boolean logic.
Arbeitsblatt mit dem Namen 'Tabelle1'
ABCD
1NumberLast 3 digits<1600000000 AND =840>1600000000 AND =930
21335001410410FALSCHFALSCH
31335003990990FALSCHFALSCH
41341000930930FALSCHFALSCH
51341001790790FALSCHFALSCH
61341001930930FALSCHFALSCH
71341001990990FALSCHFALSCH
81341002930930FALSCHFALSCH
91341002990990FALSCHFALSCH
101341003930930FALSCHFALSCH
111841060182182FALSCHFALSCH
121841060471471FALSCHFALSCH
131842200760760FALSCHFALSCH
141842201840840FALSCHFALSCH
151842202841841FALSCHFALSCH
161842203840840FALSCHFALSCH
171842203841841FALSCHFALSCH
181842205840840FALSCHFALSCH
191842206840840FALSCHFALSCH
201842207810810FALSCHFALSCH

<tbody>
</tbody>

ZelleFormel
B2=--RIGHT([@Number],3)
C2=AND([@Number]<1600000000,[@[Last 3 digits]]=840)
D2=AND([@Number]>1600000000,[@[Last 3 digits]]=930)

<tbody>
</tbody>
Verwendete Systemkomponenten: [Windows (32-bit) NT 6.01] MS Excel 2016
Diese Tabelle wurde mit Tab2Html (v2.6.0) erstellt. ©Gerd alias Bamberg

<tbody>
</tbody>

FALSCH is german for FALSE.
No number meets your criteria.
 
Upvote 0

Book1
A
21335001410
31335003990
41341000930
51341001790
61341001930
71341001990
81341002930
91341002990
101341003930
111841060182
121841060471
131842200760
141842201840
151842202841
161842203840
171842203841
181842205840
191842206840
201842207810
2174



Book1
A
11600000000
2930
3840
48
51341000930
61341001930
71341002930
81341003930
91842201840
101842203840
111842205840
121842206840
main


shift-del is right. We need to change the 1600000000 test in accordance with the results you want to obtain.


In A4 of main control+shift+enter, not just enter:

=SUM(IF('2174'!A2:A20<A1,IF(RIGHT('2174'!A2:A20,3)+0=A2,1))+IF('2174'!A2:A20>A1,IF(RIGHT('2174'!A2:A20,3)+0=A3,1)))

In A5 of main control+shift+enter, not just enter, and copy down:

=IF(ROWS($A$5:A5)>$A$4,"",INDEX('2174'!$A$2:$A$20,SMALL(IF(('2174'!$A$2:$A$20 < $A$1)*(RIGHT('2174'!$A$2:$A$20,3)+0=$A$2)+('2174'!$A$2:$A$20 > $A$1)*(RIGHT('2174'!$A$2:$A$20,3)+0=$A$3),ROW('2174'!$A$2:$A$20)-ROW(INDEX('2174'!$A$2:$A$20,1,1))+1),ROWS($A$5:A5))))
 
Upvote 0
Okay. I also made a mistake.
Let me show you in boolean logic.
Arbeitsblatt mit dem Namen 'Tabelle1'
ABCD
1NumberLast 3 digits<1600000000 AND =840>1600000000 AND =930
21335001410410FALSCHFALSCH
31335003990990FALSCHFALSCH
41341000930930FALSCHFALSCH
51341001790790FALSCHFALSCH
61341001930930FALSCHFALSCH
71341001990990FALSCHFALSCH
81341002930930FALSCHFALSCH
91341002990990FALSCHFALSCH
101341003930930FALSCHFALSCH
111841060182182FALSCHFALSCH
121841060471471FALSCHFALSCH
131842200760760FALSCHFALSCH
141842201840840FALSCHFALSCH
151842202841841FALSCHFALSCH
161842203840840FALSCHFALSCH
171842203841841FALSCHFALSCH
181842205840840FALSCHFALSCH
191842206840840FALSCHFALSCH
201842207810810FALSCHFALSCH

<tbody>
</tbody>

ZelleFormel
B2=--RIGHT([@Number],3)
C2=AND([@Number]<1600000000,[@[Last 3 digits]]=840)
D2=AND([@Number]>1600000000,[@[Last 3 digits]]=930)

<tbody>
</tbody>
Verwendete Systemkomponenten: [Windows (32-bit) NT 6.01] MS Excel 2016
Diese Tabelle wurde mit Tab2Html (v2.6.0) erstellt. ©Gerd alias Bamberg

<tbody>
</tbody>

FALSCH is german for FALSE.
No number meets your criteria.

view
view

it looks o.k. to me.
view

https://drive.google.com/file/d/1y-k2pdSEKC1IkSgFxQuqufxmsEyqZ4KO/view?usp=sharing
 
Upvote 0
A
21335001410
31335003990
41341000930
51341001790
61341001930
71341001990
81341002930
91341002990
101341003930
111841060182
121841060471
131842200760
141842201840
151842202841
161842203840
171842203841
181842205840
191842206840
201842207810

<colgroup><col style="width: 25pxpx"><col></colgroup><thead>
</thead><tbody>
</tbody>
2174

A
11600000000
2930
3840
48
51341000930
61341001930
71341002930
81341003930
91842201840
101842203840
111842205840
121842206840

<colgroup><col style="width: 25pxpx"><col></colgroup><thead>
</thead><tbody>
</tbody>
main

shift-del is right. We need to change the 1600000000 test in accordance with the results you want to obtain.


In A4 of main control+shift+enter, not just enter:

=SUM(IF('2174'!A2:A20<a1,if(right('2174'!a2:a20,3)+0=a2,1))+if('2174'!a2:a20>A1,IF(RIGHT('2174'!A2:A20,3)+0=A3,1)))

In A5 of main control+shift+enter, not just enter, and copy down:

=IF(ROWS($A$5:A5)>$A$4,"",INDEX('2174'!$A$2:$A$20,SMALL(IF(('2174'!$A$2:$A$20 < $A$1)*(RIGHT('2174'!$A$2:$A$20,3)+0=$A$2)+('2174'!$A$2:$A$20 > $A$1)*(RIGHT('2174'!$A$2:$A$20,3)+0=$A$3),ROW('2174'!$A$2:$A$20)-ROW(INDEX('2174'!$A$2:$A$20,1,1))+1),ROWS($A$5:A5))))


Thank you
i got an error in:
=SUM(IF('2174'!A2:A20<a1,if(right('2174'!a2:a20,3)+0=a2,1))+if('2174'!a2:a20>A1,IF(RIGHT('2174'!A2:A20,3)+0=A3,1)))

when i have trid to add "," A20,A1 i get
304000000

<tbody>
</tbody>

the condition should be =OR(AND(B2<1600000000,VALUE(RIGHT(B2,3))=930),AND(B2>1600000000,VALUE(RIGHT(B2,3))=840))

can i do it in one cell (the table starts with a1 title, a2 data).

I have tried to do it like:
=IF(ROWS($A$5:A5)>$A$4,"",INDEX('2174'!A:A,SMALL(IF(('2174'!A:A < $A$1)*(RIGHT('2174'!A:A,3)+0=$A$2)+('2174'!A:A > $A$1)*(RIGHT('2174'!A:A,3)+0=$A$3),ROW('2174'!A:A)-ROW(INDEX('2174'!A:A,1,1))+1),ROWS($A$5:A5))))

with control+shift+enter



</a1,if(right('2174'!a2:a20,3)+0=a2,1))+if('2174'!a2:a20></a1,if(right('2174'!a2:a20,3)+0=a2,1))+if('2174'!a2:a20>
 
Upvote 0
If you are familiar with Power Query then you can use this M-Code.

Code:
let
    Source = Excel.CurrentWorkbook(){[Name="tbl_Data"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Number", Int64.Type}}),
    #"Duplicated Column" = Table.DuplicateColumn(#"Changed Type", "Number", "Number - Kopie"),
    #"Extracted Last Characters" = Table.TransformColumns(#"Duplicated Column", {{"Number - Kopie", each Text.End(Text.From(_, "de-DE"), 3), type text}}),
    #"Renamed Columns" = Table.RenameColumns(#"Extracted Last Characters",{{"Number - Kopie", "Last 3 digits"}}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Renamed Columns",{{"Last 3 digits", Int64.Type}}),
    #"Filtered Rows" = Table.SelectRows(#"Changed Type1", each [Number] > 1600000000 and [Last 3 digits] = 840 or [Number] < 1600000000 and [Last 3 digits] = 930),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Last 3 digits"})
in
    #"Removed Columns"

Adapt Name="tbl_Data" to your need.
 
Upvote 0

Forum statistics

Threads
1,214,911
Messages
6,122,198
Members
449,072
Latest member
DW Draft

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