Using FILTER/UNIQUE on text, numbers

danhendo888

Board Regular
Joined
Jul 15, 2019
Messages
167
Office Version
  1. 365
Platform
  1. Windows
I download the below spreadsheet daily from our software. It shows details of invoices paid/booked.
*It doesn't show it below but the first three columns have the little green ribbon on the top left corner of the cell and is aligned to the left of the cell and has General formatting.

Company NumberInvoice NumberOrder NumberOrder DateOrder TaxOrder SubtotalCurrencyPayment Date
1111111111ABC123 y81900901203/12/202410.00100.00AUD
1111111111ABC123 y81900901203/12/202450.00500.00AUD
1111111111ABC123 y81900901203/12/20240.000.00AUD3/14/2024
1111111111ABC123 y81900901203/12/20240.000.00AUD3/14/2024
222222222211122200081900900001/1/20240.0010,000.00AUD


Below is my own spreadsheet. I type in the invoice number and retrieve the Order Number, Order Total, and Payment Date from the downloaded file.
The first column has the little green ribbon at the top left corner also.
The last three columns is the output I wish to achieve
Company NumberInvoice NumberOrder NumberOrder TotalPayment Date
1111111111ABC12381900901206603/14/2024
2222222222111222000819009000010,000.00


Order Number:
To retrieve the Order Number, I use FILTER and UNIQUE. It retrieves it successfully when the invoice number in my spreadsheet has text formatting e.g. ABC123
But it doesn't work when the invoice number in my spreadsheet has number formatting because the invoice numbers in the downloaded file does not have number formatting. How can I make the formula work for both text and numbers.

Also, how can I retrieve the correct order number when the correct invoice number is "ABC123" but it was incorrectly booked as "ABC123 y"

Order Total:
I use two SUMIFS to add the Order Tax and Order Subtotal columns together.
Is there a more efficient way to add these? Or is this okay to use.

Payment Date:
How can I retrieve the payment date for invoice ABC123? The date does not necessarily show in all rows in the extracted data
 
I’m on the road today and won’t be able to send a workaround for a day, but briefly, the BYROW LAMBDA helper function has some limitations in that it will allow only a single result to be returned (not a spilling array), whereas the FILTER version of the formula creates an array of the results and spills them. There are ways to do what you’ve attempted by wrapping the attempted function with DROP and REDUCE.
 
Upvote 1

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.
I’m on the road today and won’t be able to send a workaround for a day, but briefly, the BYROW LAMBDA helper function has some limitations in that it will allow only a single result to be returned (not a spilling array), whereas the FILTER version of the formula creates an array of the results and spills them. There are ways to do what you’ve attempted by wrapping the attempted function with DROP and REDUCE.
Oh of course! I missed this point completely.

No workaround will be necessary, thank you Kirk. Please ignore my post
My post was actually unrelated to the OP and was more of a sanity check on my incorrect formula which I was misinterpreting.
 
Upvote 0
I'll offer something anyway. Keeping in the spirit of what you attempted, you can always use TEXTJOIN to combine everything generated by the function inside the LAMBDA into a single cell...and then there is no problem using BYROW. As a sanity check, the formula below does this and may be sufficient to at least verify what is returned:
Excel Formula:
=BYROW(B19:B20,LAMBDA(in,TEXTJOIN(",",0,FILTER(A2:H16,ISNUMBER(SEARCH(in,INDEX(A2:H16,,2))),EXPAND("",1,COLUMNS(A2:H16),"")))))

Taking this one step further, we can concatenate a comma to the end of each row (see the &"," inside the LAMBDA) so that each of the BYROW returns ends with a comma. Then we CONCAT everything so that the entire set of results would exist in only one cell as comma-separated data. Then we can TEXTSPLIT by comma to create a very wide, multi-column, single-row array. Then we wrap this multi-column result, creating a new row every 8 cells (COLUMNS(A2:H16)), and then DROP the final meaningless row that was generated by the last hanging comma. This generates an easy-to-inspect output array containing all of the results.
Excel Formula:
=DROP(WRAPROWS(TEXTSPLIT(CONCAT(BYROW(B19:B20,LAMBDA(in,TEXTJOIN(",",0,FILTER(A2:H16,ISNUMBER(SEARCH(in,INDEX(A2:H16,,2))),EXPAND("",1,COLUMNS(A2:H16),"")))&"," ))),","),COLUMNS(A2:H16)),-1)

This is one of several strategies for handling an output that spills across and down.
 
Upvote 0

Forum statistics

Threads
1,221,418
Messages
6,159,791
Members
451,589
Latest member
Harold14

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