Consolidating a range into a concise table

Dan5977

Board Regular
Joined
Aug 7, 2008
Messages
111
Office Version
  1. 2010
Hi all,

I'm having a bit of trouble in creating a table from my raw data. I have pulled in data from various places to create a table (as shown in the raw data section below).

I now need to condense this list so that blanks are ignored and where rows are the same (apart from quantity) it counts them to create a cutting list.

For example. In the table shown below, there would be 7 occurences of the 3500 long rail (DIM. "L" being the length of a rail), so I would have that listed once with a quantity of 7 rather than having and identical part listed on many rows. There are also some other types that occur more than once.

It is important that they are only combined when all info in columns C to H matches. Otherwise they are a different part for manufacturing.

I intend to put the sorted data in the consolidated table area shown below.

Example sheet can be found here: table data.xlsx

2rm9nb8.jpg


Any help is greatly appreciated as always.

Dan.
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
Dan5977,

Thanks for the workbook.

In the below screenshots the merged cells are not showing correctly.

Sample raw data:


Excel 2007
ABCDEFGHIJKLMNOPQ
1QTYDIM. "L"DIM. "A"DIM. "B"DIM "C"OVERLAP HOLES REQ'D @ "X" ?OVERLAP HOLES REQ'D @ "Y" ?
2LH RAIL12260150N/AN/ANoNo
31336015015301530NoNo
4128801509801600NoYes
51350015016001600YesYes
61350015016001600YesYes
71350015016001600YesYes
8128801509801600NoYes
91350015016001600YesYes
1011720150N/AN/ANoNo
11
12MID RAIL
13
14
15
16
17
181350015016001600YesYes
192350015016001600YesYes
20
21
22RH RAIL
23
2411280150N/AN/AYesNo
2511560150N/AN/AYesNo
2612160150N/AN/AYesNo
271326015016001360YesNo
2811280150N/AN/AYesNo
2912160150N/AN/AYesNo
30
31
32
Armco Lengths Table


After the macro:


Excel 2007
KLMNOPQ
1QTYDIM. "L"DIM. "A"DIM. "B"DIM "C"OVERLAP HOLES REQ'D @ "X" ?OVERLAP HOLES REQ'D @ "Y" ?
221280150N/AN/AYesNo
311560150N/AN/AYesNo
411720150N/AN/ANoNo
522160150N/AN/AYesNo
612260150N/AN/ANoNo
7228801509801600NoYes
81326015016001360YesNo
91336015015301530NoNo
107350015016001600YesYes
11
Armco Lengths Table


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
2. Open your NEW 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
7. Press the keys ALT + Q to exit the Editor, and return to Excel
8. To run the macro from Excel press ALT + F8 to display the Run Macro Dialog. Double Click the macro's name to Run it.

Code:
Sub ConsolidateData()
' hiker95, 08/19/2014, ME799850
Dim r As Long, lr As Long, n As Long
Application.ScreenUpdating = False
With Sheets("Armco Lengths Table")
  .Columns("K:R").ClearContents
  lr = .Cells(Rows.Count, "B").End(xlUp).Row
  .Range("B1:H1").Copy .Range("K1:Q1")
  Application.CutCopyMode = False
  .Range("K2:Q" & lr).Value = .Range("B2:H" & lr).Value
  .Range("K1:Q" & lr).HorizontalAlignment = xlCenter
  lr = .Cells(Rows.Count, "K").End(xlUp).Row
  .Range("K1:Q" & lr).SpecialCells(xlCellTypeBlanks).Delete xlShiftUp
  lr = .Cells(Rows.Count, "K").End(xlUp).Row
  With .Range("R2:R" & lr)
    .FormulaR1C1 = "=RC[-6]&RC[-5]&RC[-4]&RC[-3]&RC[-2]&RC[-1]"
    .Value = .Value
  End With
  .Range("K2:R" & lr).Sort key1:=.Range("R2"), order1:=1
  For r = 2 To lr
    n = Application.CountIf(.Columns(18), .Cells(r, 18).Value)
    If n > 1 Then
      .Range("K" & r).Value = Evaluate("=Sum(K" & r & ":K" & r + n - 1 & ")")
      .Range("K" & r + 1 & ":Q" & r + n - 1).ClearContents
    End If
    r = r + n - 1
  Next r
  .Columns(18).ClearContents
  .Range("K2:Q" & lr).SpecialCells(xlCellTypeBlanks).Delete xlShiftUp
  .Columns("K:Q").AutoFit
End With
Application.ScreenUpdating = True
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 ConsolidateData macro.


Let me know if you actually need the results below the raw data, and, I will adjust the macro.
 
Last edited:
Upvote 0
Or if you wish to stick with formulas.....

Have utilised two 'helper' columns which you can hide if you wish.

Excel 2007
JK
2HelperHelper
32260150N/AN/ANoNo3
4336015015301530NoNo4
528801509801600NoYes5
6350015016001600YesYes6
7350015016001600YesYes
8350015016001600YesYes
928801509801600NoYes
10350015016001600YesYes
111720150N/AN/ANoNo11
12
13
14
15
16
17
18
19350015016001600YesYes
20350015016001600YesYes
21
22
23
24
251280150N/AN/AYesNo25
261560150N/AN/AYesNo26
272160150N/AN/AYesNo27
28326015016001360YesNo28
291280150N/AN/AYesNo
302160150N/AN/AYesNo
31
32
Armco Lengths Table
Cell Formulas
RangeFormula
J3=C3:C32&D3:D32&E3:E32&F3:F32&G3:G32&H3:H32
K3=IF(J3<>"",IF(COUNTIF($J$3:$J3,J3)=1,ROW(),""),"")



Formula ib B36 drag down. Formula in C36 drag across and down.
May wish to go to Excel options >> Display Options for worksheet and untic 'Show Zero in cells that have zero value'


Excel 2007
ABCDEFGH
34CONSOLIDATED TABLE
35QTYDIM. "L"DIM. "A"DIM. "B"DIM "C"OVERLAP HOLES REQ'D @ "X" ?OVERLAP HOLES REQ'D @ "Y" ?
3612260150N/AN/ANoNo
371336015015301530NoNo
38228801509801600NoYes
397350015016001600YesYes
4011720150N/AN/ANoNo
4121280150N/AN/AYesNo
4211560150N/AN/AYesNo
4322160150N/AN/AYesNo
441326015016001360YesNo
45
46
47
Armco Lengths Table
Cell Formulas
RangeFormula
B36=SUMIF($J$3:$J$32,INDEX($J$3:$J$32,MATCH(SMALL($K$3:$K$32,ROWS(B$36:B36)),$K$3:$K$32,0)),$B$3:$B$32)
C36=IFERROR(INDEX(C$3:C$32,MATCH(SMALL($K$3:$K$32,ROWS(C$36:C36)),$K$3:$K$32,0)),"")


Hope that helps.
 
Upvote 0
Many thanks to both of you.

I'm using Tony's solution purley because I am able to understand it. It's one of those where I wouldn't have been able to write the formulas but am able to understand how they work now I can see them.

Much appreciated.
 
Upvote 0
Dan5977,

Thanks for the feedback.

You are very welcome. Glad we could help.

And, come back anytime.
 
Upvote 0
@ Dan - You are welcome.

@ Hiker - As you may know, in the past I have passed your list on to folk who have asked me to suggest educational material.
Several weeks back my internet favourites got blasted into oblivion and the link to your list is no more.
I know that you update it from time to time. Would you be kind enough to post back with your latest link.

Regards Tony
 
Upvote 0
Snakehips,

in the past I have passed your list on to folk who have asked me to suggest educational material

Thank you for doing that.


Here is the most up to date list - it has not been posted yet, but, I will add this post link to the list.


Training / Books / Sites as of 8/19/2014

What Is VBA?
VBA is an acronym for Visual Basic for Applications. VBA should not be confused with VB, which is standard Visual Basic. Visual Basic for Applications is a programming feature designed by Microsoft for use with their Microsoft Office

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 - YouTube

Getting Started with VBA.
DataPig Technologies

If you are serious about learning VBA try
http://www.add-ins.com/vbhelp.htm

Excel Tutorials and Tips - VBA - macros - training
MrExcel.com | Excel Resources | Excel Seminars | Excel Products

MrExcel's Excel Tutorial Listing
MrExcel.com | Excel Resources | Excel Seminars | Excel Products

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 VBA Module and How is a VBA Module Used?
What Is A VBA Module and how is a VBA Module Used?

Events And Event Procedures In VBA
Events In Excel VBA

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

There's a chapter on classes in VBA Developer's Handbook which is also good.
VBA Developer's Handbook, 2nd Edition: Ken Getz, Mike Gilbert: 0025211229781: Amazon.com: Books

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)

How do I create and use a PERSONAL file for my VBA code
How do I create and use a PERSONAL file for my VBA code

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

BET: Microsoft Excel Visual Basic

Debugging VBA
Debug Excel VBA Macro Code
TechBookReport - Debugging Excel VBA Code

Start at the beginning...

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

Build an Excel Add-In
VBA Tips: Build an Excel Add-In

Creating custom functions
Creating custom functions - Excel

Writing Your First VBA Function in Excel
Writing Your First VBA Function in Excel | Custom Functions

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

Excel Macros Tutorial
Excel Macros (VBA) Tutorial

Excel Macros & Programming
EXCEL Macros Tutorial

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

Excel VBA -- Adding Code to a Workbook
http://www.contextures.com/xlvba01.html

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

User Form Creation
http://www.contextures.com/xlUserForm01.html

Build a UserForm for Excel
http://www.fontstuff.com/ebooks/free/fsuserforms.pdf

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
http://www.contextures.com/xlFunctions02.html

How to insert Buttons, radio buttons and check boxes in Excel
How to insert Buttons, radio buttons and check boxes in Excel - Bing Videos

INDEX MATCH - Excel Index Function and Excel Match Function
http://www.contextures.com/xlFunctions03.html

Multi or two way vlook up and index match tutorial
Get Digital Help - Excel formulas, array formulas, vba, charts, pivot tables, templates and much more.

Excel Data Validation
http://www.contextures.com/xlDataVal08.html#Larger
http://www.contextures.com/excel-data-validation-add.html

Excel -- Data Validation -- Create Dependent Lists
http://www.contextures.com/xlDataVal02.html

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

John Walkenbach's power programming with Excel books.

Excel 2010 Power Programming with VBA, Mr. Spreadsheet's Bookshelf

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

A list of Reference Books
AJP Excel Information

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

Arrays
VBA Array Basics
VBA Arrays
Excel: Introduction to Array Formulas - Xtreme Visual Basic Talk
Excel VBA Chpter 21: 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
http://www.contextures.com/xlPivot01.html#Start
Overview of PivotTable and PivotChart reports
Overview of PivotTable and PivotChart reports - Excel
Build a Pivot Table in Excel VBA
Excel VBA - Build A Pivot Table In Excel VBA Tutorials

Conditional Formatting
Use a formula to apply conditional formatting - Excel

Email from XL - VBA
Mail from Excel example pages

Outlook VBA
Writing VBA code for Microsoft Outlook

Excel Function Dictionary by Peter Noneley
http://www.xlfdic.com/
www.xlfdic.com Excel Function Dictionary 150 example functions and formula.

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

Dynamic Named Ranges
http://www.contextures.com/xlNames01.html

How to create Excel Dashboards
http://www.contextures.com/excel-dashboards.html
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
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: 9780470228142: Computer Science Books @ Amazon.com

Templates
CPearson.com Topic Index
http://www.contextures.com/excel-template-golf-scores.html
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
Progress meters
xcelfiles.com

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

How to parse data from the web - Brett Fret has a video in YouTube
Excel VBA - Easily parse XML data from a file or website using XML Maps - YouTube

Excel VBA MAC shortcuts
http://www.mrexcel.com/forum/excel-questions/465614-mac-shortcuts-excel.html

Macintosh Keyboard Shortcuts to use in Microsoft Excel
Excel keyboard shortcuts - mac excel

Excel shortcut and function keys - Excel

And, as your skills increase, try answering threads 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
Expert Microsoft Help, with all of the Microsoft Applications from Excel programming, Access training to our free Microsoft VBA Forums
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

Advanced Excel Training - Online Excel Course
Advanced Excel Training - Online Excel Course

Excel VBA Programmer Interview - Excel Test for interview
Excel VBA Programmer Interview
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,910
Messages
6,175,320
Members
452,635
Latest member
laura12345

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