Automatically Pull Data from another Sheet to another sheet based on Criteria

himaruasuka

New Member
Joined
May 26, 2022
Messages
12
Office Version
  1. 2013
Platform
  1. Windows
  2. Mobile
Good day!

I am curious if there is a way to pull a data from another sheet to another sheet. For example, I have an ORDER LIST where you can see all the orders 'delivered', 'unpaid', 'on-queue', and 'for delivery' statuses.
Capture.PNG


I want to make another sheet where you can 'filter-out' only the Unpaid or For Delivery or for On-Queue, like the picture below.
sd.PNG

I have found one which I currently using, an array formula:
VBA Code:
{=IFERROR(INDEX(ORDER!$B:$B,SMALL(IF(ORDER!$Q:$Q="FOR DELIVERY",ROW(ORDER!$B:$B)),ROW(ORDER!1:7))-0,1),"")}

This formula is working but It's too hassle to use it because of the calculating process is takes long time.
Capture2.PNG


is there an alternative formula to use for this? your helping hand is much appreciated! Thanks in advance !
 

Attachments

  • Capture.PNG
    Capture.PNG
    23.3 KB · Views: 7

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
I wouldn't use VBA for this task when the data model is faster to set up, easier to use and won't break if your data structure changes.

The excel data model gives you more flexibility in formatting and also allows you to add additional formula columns that won't affect your source data set.
  1. Convert your sheet data into a ListObject Table if you haven't already done so.
    HOME > Format as Table

  2. Then add it to the datamodel
    click table > Power Pivot > Add to data model

  3. Then pull it back down into the spreadsheet/s of your choice.
    Home> Get Data using an existing connection (orange database icon) > tables tab > click your table > use the dialog to place where it should go.
Please note my instructions may be slightly different to yours as I'm using Office 365.
 
Upvote 0
because of the calculating process is takes long time.
That's because you are using whole column references, which you should not do (especially with an array formula) try limiting the range like
Excel Formula:
=IFERROR(INDEX(ORDER!$B$4:$B$1000,SMALL(IF(ORDER!$Q$4:$Q$1000="FOR DELIVERY",ROW(ORDER!$B$4:$B$1000)-ROW(ORDER!$B$4)+1),ROWS(A$1:A1)),1),"")
 
Upvote 0

Forum statistics

Threads
1,223,236
Messages
6,170,912
Members
452,366
Latest member
TePunaBloke

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