Filter months and name

iggydarsa

Well-known Member
Joined
Jun 28, 2005
Messages
1,647
Hi everyone,

I am trying to use filter options with VBA, I appretiate any help.

I have a sheet (Sheet1) with information of:

Date.....ProductName....Price....Cost
1-Mar.......ProdA...........10.........7
1-Mar.......ProdA...........10.........7
3-Mar.......ProdB...........12.........7
4-Apr........ProdA...........11........6
7-Apr........ProdB...........14........6 etc...

I am trying to create a userform that will have

1- Begining Month combobox (cbBeginMonth): I don't know how to populate the name of the months without writing it somewhere on the sheet and assign it to the RowSource.

2- Ending Month combobox (cbEndMonth): As I mentioned above, how can I populate the names of the months without typing them somewhere on the sheet?

3- Product Name combobox (cbProdName): No problem with this one, I can populate it.

Lets say someone chose "March" from the cbBeginMonth, "October" from cbEndMonth and "ProdA" from the cbProdName
I would like to see the subtotals of Price and Cost of ProdA within the dates of 1-Mar and 31-Oct.

PS: Even though the date format on the sheet is "4-Apr", I just want to see "April" on the comboboxes.

I hope I was clear enough
and again, I appretiate any help

Thanks
 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.

acw

MrExcel MVP
Joined
Feb 13, 2004
Messages
4,814
Hi

1) to add the months try adding this to the form initialize

Code:
Private Sub UserForm_Initialize()
For i = 1 To 12
 cbBeginMonth.AddItem Format("1/" & i, "mmmm")
 cbEndMonth.AddItem Format("1/" & i, "mmmm")
Next i

End Sub

2) For the outputs, I've assumed there are 2 textboxes to take the output and there is a command button to initiate. This is the code for the command button
Code:
Private Sub CommandButton1_Click()
lastrow = Sheets("sheet1").Cells(Rows.Count, "A").End(xlUp).Row
TextBox1.Value = Evaluate("=SUMPRODUCT(--(MONTH(A2:A" & lastrow & ")>=MONTH(""1/" & cbBeginMonth.Value & """)),--(MONTH(A2:A" & lastrow & ")<=MONTH(""1/" & cbEndMonth.Value & """)),--(B2:B" & lastrow & "=""" & cbProdName.Value & """),(C2:C" & lastrow & "))")
TextBox2.Value = Evaluate("=SUMPRODUCT(--(MONTH(A2:A" & lastrow & ")>=MONTH(""1/" & cbBeginMonth.Value & """)),--(MONTH(A2:A" & lastrow & ")<=MONTH(""1/" & cbEndMonth.Value & """)),--(B2:B" & lastrow & "=""" & cbProdName.Value & """),(D2:D" & lastrow & "))")
End Sub


HTH

Tony
 

iggydarsa

Well-known Member
Joined
Jun 28, 2005
Messages
1,647
Thanx Tony,

Beacuse I am on another computer I couldn't try your solution YET, but populating the comboboxes with month names looks about right.

However, I have a question about SUMPRODUCT part of your answer. What is the reason for "--" before the MONTH funtion. What purpose does it serve?

Thanks again
Iggy
 

acw

MrExcel MVP
Joined
Feb 13, 2004
Messages
4,814
Iggy

It converts the true/false result into a number. THe first - will make it negative, the second will make it positive again. This way you are multiplying numbers in the sumproduct function.


Tony
 

Watch MrExcel Video

Forum statistics

Threads
1,133,243
Messages
5,657,575
Members
418,401
Latest member
B_A_M155

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
Top