Advanced filtering or index/match problem

excelhjalp

New Member
Joined
Aug 7, 2018
Messages
33
Office Version
  1. 365
Platform
  1. Windows
Hello!

I have a range with columns "Product", "Type" and very many date columns, the one on the left in XL2bb. This shows the inventory for each day. Please note that in reality the products, type and dates are way more than in this example.
I need to create a table (the one on the right in Xl2bb) that filters out the instances where the inventory is <0 and shows what product is missing, it's type, how many are missing and which dates.

Thank you in advance!

qqqqq (1).xlsx
ABCDEFGHIJKLMNOPQRSTUVWX
1ProductType1.9.20222.9.20223.9.20224.9.20225.9.20226.9.20227.9.20228.9.20229.9.202210.9.202211.9.202212.9.202213.9.2022
2A10000000000000
3A22222222222222ProductTypeMissingDate
4A33333333333333A4-18.9.2022
5A40000000-1-1-1-1-1-1A4-19.9.2022
6A56666666666666A4-110.9.2022
7A62222222222222A4-111.9.2022
8A72222222222222A4-112.9.2022
9A81111111111111A4-113.9.2022
10B1022-2-2222222200B10-23.9.2022
11B203333333333333B10-24.9.2022
12B304444444444444B50-34.9.2022
13B404444444444444B50-35.9.2022
14B50111-3-311111111
15C10000000000000
16C24444444222223
17C37777777774446
18C44444444444444
19
20
21
22
Sheet2
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
Try this macro:
Your data in Sheet2, results in Sheet3

VBA Code:
Sub AdvancedFiltering()
  Dim i As Long, j As Long, k As Long, lr As Long, lc As Long
  Dim a As Variant, b As Variant
  
  With Sheets("Sheet2")
    lr = .Range("A" & Rows.Count).End(3).Row
    lc = .Cells(1, Columns.Count).End(1).Column
    a = .Range("A1", .Cells(lr, lc)).Value
  End With
  ReDim b(1 To UBound(a, 1), 1 To 4)
  
  For i = 2 To UBound(a, 1)
    For j = 3 To UBound(a, 2)
      If a(i, j) < 0 Then
        k = k + 1
        b(k, 1) = a(i, 1)
        b(k, 2) = a(i, 2)
        b(k, 3) = a(i, j)
        b(k, 4) = a(1, j)
      End If
    Next
  Next
  
  With Sheets("Sheet3")
    .Range("A1").Resize(1, 4).Value = Array("Product", "Type", "Missing", "Date")
    .Range("A2").Resize(k, 4).Value = b
  End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,923
Messages
6,175,398
Members
452,640
Latest member
steveridge

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