Produce a unique, dynamic list based on multiple criteria

sbrien

New Member
Joined
Jun 5, 2012
Messages
19
I hope I can explain this clearly, as I've had trouble searching for results online.
My work computer seems to be preventing me from installing the HTMLmaker, so I'll try to explain as best I can.

I have a database of employees and their clocked hours worked.
I'm trying to create a tool that can produce a list of the employees on a separate page who match a few criteria (store, date) that are selected on that separate page.
I toyed around with advanced filter, but I couldn't find a way to get the filters to use referenced cells.

I really appreciate any help you can offer.

All the best,
SB
 

Excel Facts

Excel Can Read to You
Customize Quick Access Toolbar. From All Commands, add Speak Cells or Speak Cells on Enter to QAT. Select cells. Press Speak Cells.
sbrien,

We can not tell where your raw data is located, cells, rows, columns,
and, we can not tell where the results should be, cells, rows, columns.

You can upload your workbook to Box Net,
sensitive data changed
mark the workbook for sharing
and provide us with a link to your workbook.
 
Upvote 0
Thanks hiker95 for the Box Net tip.

Here's a link to the file. https://www.box.com/s/<wbr>2zgu8e4eekm81cq8efnm

Ultimately, I need to sum the hours for each employee in the second column, but getting the filtered, unique employee numbers in the first column is where I'm stumped.
The real file will be pulling from a database of hundreds of thousands of rows of data, so any solution would need to be able to manage that.

Thanks!
SB
 
Upvote 0
sbrien,

Thanks for the workbook.

Sample raw data in worksheet Data:


Excel 2007
ABCD
1Employee #PlantDateHours
211015/1/20134.5
311015/1/20133
411015/2/20134
511015/2/20135
611015/4/20133
711015/4/20134
822025/1/20133.5
922025/1/20133
1022025/2/20131
1122025/2/20136
1222025/5/20133
1322025/5/20132
1422025/8/20133
1522025/8/20135
1631015/4/20135
1731015/4/20134
1831015/5/20135
1931015/5/20132
2042025/1/20135
2142025/1/20134
2242025/8/20135
2342025/8/20133
24
Data


Sample worksheet Tool before the macro:


Excel 2007
BCD
2Store NumberDate
31015/4/2013
4
5Employee #Hours
6
7
8
9
10
11
12
13
14
15
16
Tool


After the macro:


Excel 2007
BCD
2Store NumberDate
31015/4/2013
4
5Employee #Hours
617
739
8
9
10
11
12
13
14
15
16
Tool


If we change our search criteria:


Excel 2007
BCD
2Store NumberDate
31015/2/2013
Tool


And run the macro again:


Excel 2007
BCD
2Store NumberDate
31015/2/2013
4
5Employee #Hours
619
7
8
9
10
11
12
13
14
15
16
Tool


And, another change:


Excel 2007
BCD
2Store NumberDate
32025/1/2013
Tool


Then we get this:


Excel 2007
BCD
2Store NumberDate
32025/1/2013
4
5Employee #Hours
626.5
749
8
9
10
11
12
13
14
15
16
Tool


Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).

1. Copy the below code, by highlighting the code and pressing the keys CTRL + C
2. Open your workbook
3. Press the keys ALT + F11 to open the Visual Basic Editor
4. Press the keys ALT + I to activate the Insert menu
5. Press M to insert a Standard Module
6. Where the cursor is flashing, paste the code by pressing the keys CTRL + V
7. Press the keys ALT + Q to exit the Editor, and return to Excel
8. To run the macro from Excel, open the workbook, and press ALT + F8 to display the Run Macro Dialog. Double Click the macro's name to Run it.

Code:
Option Explicit
Sub GetEmpNbrHrs()
' hiker9, 05/29/2013
' http://www.mrexcel.com/forum/excel-questions/705443-produce-unique-dynamic-list-based-multiple-criteria.html
Dim d As Variant, t As Variant, e
Dim sn As Long, sd As Variant
Dim lr As Long, i As Long, ii As Long, n As Long, fr As Long
With Sheets("Tool")
  lr = .Cells(Rows.Count, 2).End(xlUp).Row
  If lr > 5 Then
    .Range("B6:C" & lr).ClearContents
  End If
End With
d = Sheets("Data").Cells(1).CurrentRegion
sn = Sheets("Tool").Range("B3")
sd = Sheets("Tool").Range("D3")
n = Application.CountIfs(Sheets("Data").Columns(2), Sheets("Tool").Range("B3"), Sheets("Data").Columns(3), Sheets("Tool").Range("D3"))
If n = 0 Then
  MsgBox "There are no entries in Sheets 'Data' with 'Store Number' " & sn & " and/or 'Date' " & sd & " - macro terminated!"
  Exit Sub
End If
ReDim t(1 To n, 1 To 2)
ReDim e(1 To UBound(d, 1))
n = 0
For i = 2 To UBound(d, 1)
  If d(i, 2) = sn And d(i, 3) = sd Then
    fr = 0
    On Error Resume Next
    fr = Application.Match(d(i, 1), e, 0)
    On Error GoTo 0
    If fr = 0 Then
      n = n + 1
      e(n) = d(i, 1)
      ii = ii + 1
      t(ii, 1) = d(i, 1)
      t(ii, 2) = d(i, 4)
    Else
      t(fr, 2) = t(fr, 2) + d(i, 4)
    End If
  End If
Next i
Sheets("Tool").Range("B6").Resize(UBound(t, 1), UBound(t, 2)).Value = t
Sheets("Tool").Activate
End Sub

Before you use the macro with Excel 2007 or newer, save your workbook, Save As, a macro enabled workbook with the file extension .xlsm

Then run the GetEmpNbrHrs macro.

If the macro does not find any data based on the two selections, you will get an error message.
 
Upvote 0
Thanks hiker95. This is fantastic.
I'm working my way through a VBA book but I'm sure dissecting this code will teach me a fair bit.

All the best,
SB
 
Upvote 0
sbrien,

You are very welcome. Glad I could help.

Thanks for the feedback.

And, come back anytime.


I'm working my way through a VBA book but I'm sure dissecting this code will teach me a fair bit.

Training / Books / Sites as of 5/30/2013

MrExcel's Products: Books, CDs, Podcasts Discuss topics related to Holy Macro! Products: Learn Excel from MrExcel, VBA and Macros for Microsoft Excel,Holy Macro! It's 2500 VBA Examples CD, Guerilla Data Analysis Using Microsoft Excel and Excel Knowledge Base CD and the MrExcel Podcasts.
MrExcel's Products: Books, CDs, Podcasts

There are over 1800 Excel videos/tutorials here:
excelisfun -- Excel How To Videos - YouTube

Getting Started with VBA.
DataPig Technologies

If you are serious about learning VBA try
Macros Made Easy for Microsoft Excel

Excel Tutorials and Tips - VBA - macros - training
Excel Tutorial | Excel Tips | Excel Articles

Free VBA Course
Free VBA Course

Excel 2007 VBA materials to learn here:
VBA for Excel 2007 tutorial-VBA programming?

Here's a good primer on the scope of variables.
Understanding Scope

Using Variables in Excel VBA Macro Code
Excel VBA Variables. Using Variables in Excel VBA Macro Code

See David McRitchie's site if you just started with VBA
Getting Started with Macros and User Defined Functions

What is a Visual Basic Module?
What Is A VBA Module and how is a VBA Module Used?

Here is a good introductory tutorial using a VBA Class:
Classes In VBA

Ron de Bruin's intro to macros:
http://www.rondebruin.nl/code.htm

Ron's Excel Tips
Excel for Windows Tips

Ron de Bruin's Mail from Excel and make/mail PDF files (Windows)
Mail from Excel and make/mail PDF files (Windows)

Anthony's Excel VBA Page - Excel Application - Excel Consultant - Excel Consulting (see 3 tutorials in Excel VBA Basic Tutorial Series)

http://www.jlathamsite.com/Teach/VBA...troduction.pdf (95 page "book")

BET: Microsoft Excel Visual Basic

Creating An XLA Add-In For Excel, Writing User Defined Functions In VBA
Creating An XLA Add In

How do I create a PERSONAL.XLS(B) or Add-in
http://www.rondebruin.nl/personal.htm

Creating custom functions
Creating custom functions - Excel - Office.com

Writing Your First VBA Function in Excel
Writing Your First VBA Function in Excel

VBA for Excel (Macros)
Excel Macros (VBA) Tutorial

Excel Macros Tutorial
Excel Macros (VBA) Tutorial

Excel Macros & Programming
Learning about EXCEL macros

VBA Lesson 11: VBA Code General Tips and General Vocabulary
VBA for Excel macros language

Excel VBA -- Adding Code to a Workbook
Excel VBA -- Adding Code to Excel Workbook

Beyond Excel's recorder

Helpful as a simple concise reference for the basics, and, using the macro recorder is endlessly powerful.
MS Excel: Cells

Learn to debug:
Debugging VBA

How To: Assign a Macro to a Button or Shape
How To: Assign a Macro to a Button or Shape | Peltier Tech Blog | Excel Charts

User Form Creation
Create an Excel UserForm

When To Use a UserForm & What to Use a UserForm For
When to use Userform & What To Use Them For. Excel Training VBA 2 lesson 2

Excel Tutorials / Video Tutorials - Functions
Excel VLookup Function Examples

INDEX MATCH - Excel Index Function and Excel Match Function
Excel Index Function and Match Function

Excel Data Validation
Excel Data Validation Tips and Quirks
Excel Data Validation - Add New Items

Excel -- Data Validation -- Create Dependent Lists
Excel Data Validation -- Dependent Lists

Your Quick Reference to Microsoft Excel Solutions
XL-CENTRAL.COM : For your Microsoft Excel Solutions

New! Excel Recorded Webinars
DataPig Technologies

Fuzzy Matching - new version plus explanation

Programming The VBA Editor - Created by Chip Pearson at Pearson Software Consulting LLC
This page describes how to write code that modifies or reads other VBA code.
Programming In The VBA Editor

VBA and Macros for Microsoft Excel, by Bill Jelen "Mr.Excel" and Tracy Syrstad

Excel Hacks 100 Industrial-Strength Tips & Tools, by David & Traina Hawley

VBA and Macros for Microsoft Excel 2007, by Bill Jelen "Mr.Excel" and Tracy Syrstad

Excel 2007 Book: you can try this...there is a try before you buy ebook available at this link…

by Stephen/ Bovey, Rob/ Green, John Bullen (Paperback - Feb 11, 2005)
Professional Excel Development

by Rob Bovey, Stephen Bullen, John Green, and Robert Rosenberg (Paperback - Sep 26, 2001)
Excel 2002 VBA: Programmers Reference

"Professional Excel Development" by Rob Bovey, Dennis Wallentin, Stephen Bullen, & John Green

DonkeyOte: My Recommended Reading, Volatility
Volatile Excel Functions -Decision Models

Sumproduct
http://www.xldynamic.com/source/xld.SUMPRODUCT.html

Arrays
VBA Array Basics
VBA Arrays
Excel: Introduction to Array Formulas - Xtreme Visual Basic Talk
Array in Excel VBA

Array Dimensions in Visual Basic - Working with Dimensions (code and graphics)
Array Dimensions in Visual Basic

Shortcut Keys in Excel 2000 through 2007

Pivot Intro
Using Pivot Tables and Pivot Charts in Microsoft Excel
Office 2010 Class #36: Excel PivotTables Pivot Tables 15 examples (Data Analysis) - YouTube
Office 2010 Class #36: Excel PivotTables Pivot Tables 15 examples (Data Analysis) - YouTube
Getting Started with Pivot Tables
Excel Pivot Table -- Dynamic Data Source
Overview of PivotTable and PivotChart reports
Overview of PivotTable and PivotChart reports - Excel - Office.com
Build a Pivot Table in Excel VBA
Excel VBA - Build A Pivot Table In Excel VBA Tutorials

Email from XL - VBA
Mail from Excel example pages

Outlook VBA
Writing VBA code for Microsoft Outlook

Function Dictionary
http://www.xlfdic.com/

Function Translations
Excel 2007 function name translations - Dictionary Chart Front Page

Dynamic Named Ranges
Excel Names -- Excel Named Ranges

How to create Excel Dashboards
http://www.mrexcel.com/Excel-dashboards-Xcelsius.html
Excel Dashboard Templates
Excel Dashboards - Templates, Tutorials, Downloads and Examples | Chandoo.org - Learn Microsoft Excel Online
Excel Dashboards - Templates, Tutorials, Downloads and Examples | Chandoo.org - Learn Microsoft Excel Online
Free Microsoft Excel Dashboard Widgets to Download
AJP Excel Information - Gauge

Excel Dashboard / Scorecard Ebook
Excel Dashboards and Scorecards Ebook | How to Create Dashboards in Excel

Mike Alexander from Data Pig Technologies
Excel 2007 Dashboards and Reports For Dummies: Michael Alexander: 9780470228142: Amazon.com: Books

Templates
CPearson.com Topic Index
Excel Template - Golf Scores
Free Microsoft Excel Template Links & Search Engine

Microsoft Excel Cascading Listboxes Tutorial
Microsoft Excel Cascading Listboxes Tutorial - YouTube

Date & Time stamping:
McGimpsey & Associates : Excel : Time and date stamps

Get Formula / Formats thru custom functions:
Show FORMULA or FORMAT of another cell

A nice informative MS article "Improving Performance in Excel 2007"
Improving Performance in Excel 2007

Progress Meters
AJP Excel Information - Progress meters
Website Disabled

How to convert text to numbers in Excel
How to convert text to numbers in Excel

And, as your skills increase, try answering posts on sites like:
MrExcel.com | Excel Resources | Excel Seminars | Excel Products
Excel Help Forum
Excel Templates | Excel Add-ins and Excel Help with formulas and VBA Macros
VBA Express Portal
Excel, Access, PowerPoint and Word VBA Macro Automation Help

If you are willing to spend money for the training, then something here should work for you...
Amazon.com: excel tutorial dvd
Amazon.com: excel tutorial dvd

Advanced Excel Training - Online Excel Course
http://www.udemy.com/advanced-excel/
 
Upvote 0

Forum statistics

Threads
1,215,537
Messages
6,125,390
Members
449,222
Latest member
taner zz

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