Sort multiple data sets in the same sheet

kapperson

Board Regular
Joined
Jan 5, 2015
Messages
59
Hello,
I've done some searching and haven't been able to find a way to do this yet.
I have multiple data sets (formatted as tables but not true Excel tables) that have the same header in Column B and a Total column to signify the top row and the last row.
I'm trying to find a way to code a macro that goes through and sorts all of these tables independently based on the values of a different column - so in the sample file below, this would be column "4."

[TABLE="width: 345"]
<colgroup><col><col span="4"></colgroup><tbody>[TR]
[TD]Table Header[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]2[/TD]
[TD="align: right"]3[/TD]
[TD="align: right"]4[/TD]
[/TR]
[TR]
[TD]A[/TD]
[TD="align: right"]5[/TD]
[TD]J[/TD]
[TD="align: right"]75[/TD]
[TD="align: right"]375[/TD]
[/TR]
[TR]
[TD]B[/TD]
[TD="align: right"]10[/TD]
[TD]K[/TD]
[TD="align: right"]500[/TD]
[TD="align: right"]2500[/TD]
[/TR]
[TR]
[TD]C[/TD]
[TD="align: right"]20[/TD]
[TD]I[/TD]
[TD="align: right"]30[/TD]
[TD="align: right"]150[/TD]
[/TR]
[TR]
[TD]D[/TD]
[TD="align: right"]30[/TD]
[TD]P[/TD]
[TD="align: right"]27[/TD]
[TD="align: right"]135[/TD]
[/TR]
[TR]
[TD]E[/TD]
[TD="align: right"]40[/TD]
[TD]O[/TD]
[TD="align: right"]47[/TD]
[TD="align: right"]235[/TD]
[/TR]
[TR]
[TD]F[/TD]
[TD="align: right"]50[/TD]
[TD]S[/TD]
[TD="align: right"]5[/TD]
[TD="align: right"]25[/TD]
[/TR]
[TR]
[TD]Total[/TD]
[TD="align: right"]155[/TD]
[TD]-[/TD]
[TD="align: right"]684[/TD]
[TD="align: right"]3420[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Table Header[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]2[/TD]
[TD="align: right"]3[/TD]
[TD="align: right"]4[/TD]
[/TR]
[TR]
[TD]B[/TD]
[TD="align: right"]100[/TD]
[TD]R[/TD]
[TD="align: right"]7[/TD]
[TD="align: right"]35[/TD]
[/TR]
[TR]
[TD]C[/TD]
[TD="align: right"]200[/TD]
[TD]S[/TD]
[TD="align: right"]25[/TD]
[TD="align: right"]125[/TD]
[/TR]
[TR]
[TD]A[/TD]
[TD="align: right"]300[/TD]
[TD]A[/TD]
[TD="align: right"]13[/TD]
[TD="align: right"]65[/TD]
[/TR]
[TR]
[TD]F[/TD]
[TD="align: right"]400[/TD]
[TD]Y[/TD]
[TD="align: right"]19[/TD]
[TD="align: right"]95[/TD]
[/TR]
[TR]
[TD]D[/TD]
[TD="align: right"]500[/TD]
[TD]X[/TD]
[TD="align: right"]54[/TD]
[TD="align: right"]270[/TD]
[/TR]
[TR]
[TD]E[/TD]
[TD="align: right"]600[/TD]
[TD]Z[/TD]
[TD="align: right"]658[/TD]
[TD="align: right"]3290[/TD]
[/TR]
[TR]
[TD]G[/TD]
[TD="align: right"]700[/TD]
[TD]K[/TD]
[TD="align: right"]26[/TD]
[TD="align: right"]130[/TD]
[/TR]
[TR]
[TD]H[/TD]
[TD="align: right"]800[/TD]
[TD]T[/TD]
[TD="align: right"]95[/TD]
[TD="align: right"]475[/TD]
[/TR]
[TR]
[TD]Total[/TD]
[TD="align: right"]2100[/TD]
[TD]-[/TD]
[TD="align: right"]776[/TD]
[TD="align: right"]4485[/TD]
[/TR]
</tbody>[/TABLE]


The number of rows in the table will not always be the same, and there will likely be more added over time, so variable references would be ideal.
I assume what the macro will have to do is loop through the cells and find the header, the total, and then sort the columns in between, I'm just not entirely sure how to code for that.

Any help would be appreciated!
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
kapperson,

Here is a macro solution for you to consider that is based on your flat text display.

You did not say how you wanted each area sorted.

The macro will sort the data (now) ascending in the column indicated by 4.

Sample raw data in the active worksheet:


Excel 2007
ABCDEFG
1Table Header1234
2A5J75375
3B10K5002500
4C20I30150
5D30P27135
6E40O47235
7F50S525
8Total155-6843420
9
10
11Table Header1234
12B100R735
13C200S25125
14A300A1365
15F400Y1995
16D500X54270
17E600Z6583290
18G700K26130
19H800T95475
20Total2100-7764485
21
Sheet1


And, after the macro:


Excel 2007
ABCDEFG
1Table Header1234
2F50S525
3D30P27135
4C20I30150
5E40O47235
6A5J75375
7B10K5002500
8Total155-6843420
9
10
11Table Header1234
12B100R735
13A300A1365
14F400Y1995
15C200S25125
16G700K26130
17D500X54270
18H800T95475
19E600Z6583290
20Total2100-7764485
21
Sheet1


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 kapperson()
' hiker95, 07/05/2017, ME1012860
Dim Area As Range, sr As Long, er As Long
Application.ScreenUpdating = False
With ActiveSheet
  For Each Area In Range("B1", Range("B" & .Rows.Count).End(xlUp)).SpecialCells(xlCellTypeConstants).Areas
    With Area
      sr = .Row + 1
      er = sr + .Rows.Count - 3
      Range("B" & sr & ":F" & er).Sort key1:=Range("F" & sr), order1:=1
    End With
  Next Area
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, and, answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.

Then run the kapperson macro.
 
Upvote 0
Hi hiker95,
Thank you again for the help! I tested the macro and it worked on the test file I provided, but when I tried to implement with my full file I had some trouble.
I think this is because of the formatting in between the tables, primarily.
Below is a link to how my actual file is set up (sans data).

https://www.dropbox.com/s/9tuqyxesti585io/FullTestFile.xlsx?dl=0

Is there a way to make it work with the report headers in between some of the tables, as shown in the file?

Thanks again for your help, and sorry for the inconvenience.
 
Upvote 0
kapperson,

When I attempted to download/open your workbook, I received the following:

Excel found unreadable content in 'FullTestFile.xlsx'. Do you want to recover the content of this workbook? If you trust the source of this workbook, click Yes.

And, the file size is 6.5 MB?????
 
Upvote 0
kapperson,

When I attempted to download/open your workbook, I received the following:

Excel found unreadable content in 'FullTestFile.xlsx'. Do you want to recover the content of this workbook? If you trust the source of this workbook, click Yes.

And, the file size is 6.5 MB?????

I apologize, it looks like there was some hidden content that didn't get deleted.
Below is a link to the new file: https://www.dropbox.com/s/9m95vcw0ys6taf1/FullTestFile.xlsx?dl=0
 
Upvote 0
kapperson,

Thanks for the latest workbook.

But, there is no raw data information?????

And, the worksheet goes out to column DX?????
 
Upvote 0
kapperson,

Thanks for the latest workbook.

But, there is no raw data information?????

And, the worksheet goes out to column DX?????

Sorry, yes, this is what my full workbook will look like without the majority of the info that shouldn't matter.
It'll sort by column DW in ascending order, which has sample values in it. I was able to alter that on your code but I believe I was having trouble because of some of the information in between the tables.

The headings for each will be the same. The width of the tables may change (however, I can change column references if necessary), and the height of the tables will definitely change, in addition to more tables potentially being added.

Please let me know if that makes sense or if you have any other questions. I really appreciate your help.
 
Upvote 0
kapperson,

Here is a macro solution for you to consider, based on your latest request.

Not all rows are shown for brevity.

Sample raw data in sections:


Excel 2007
DW
10Sort
1154.1
1272.8
1374.2
1481.7
15101.0
1685.3
17175.2
18181.0
1935.4
20152.7
2136.4
2267.0
2359.0
2423.0
25
Sheet1



Excel 2007
DW
120Sort
12154.1
12272.8
12374.2
12481.7
125101.0
12685.3
127175.2
128181.0
12935.4
130152.7
13136.4
13267.0
13359.0
13423.0
135180.0
13696.0
13717.2
13825.8
13939.7
14027.5
14141.6
14235.9
143125.1
144107.6
145115.2
146104.9
14752.8
14877.7
14962.5
15010.3
15197.4
152100.9
153101.5
154125.8
155189.7
156130.6
157
Sheet1


And, after the new macro:


Excel 2007
DW
10Sort
1123.0
1235.4
1336.4
1454.1
1559.0
1667.0
1772.8
1874.2
1981.7
2085.3
21101.0
22152.7
23175.2
24181.0
25
Sheet1



Excel 2007
DW
120Sort
12110.3
12217.2
12323.0
12425.8
12527.5
12635.4
12735.9
12836.4
12939.7
13041.6
13152.8
13254.1
13359.0
13462.5
13567.0
13672.8
13774.2
13877.7
13981.7
14085.3
14196.0
14297.4
143100.9
144101.0
145101.5
146104.9
147107.6
148115.2
149125.1
150125.8
151130.6
152152.7
153175.2
154180.0
155181.0
156189.7
157
Sheet1



With the same instructions from the first macro.

Code:
Sub kapperson_V2()
' hiker95, 07/06/2017, ME1012860
Dim Area As Range, sr As Long, er As Long
Application.ScreenUpdating = False
With ActiveSheet
  For Each Area In Range("DW1", Range("DW" & .Rows.Count).End(xlUp)).SpecialCells(xlCellTypeConstants).Areas
    With Area
      sr = .Row + 1
      er = sr + .Rows.Count - 2
      Range("DW" & sr & ":DW" & er).Sort key1:=Range("DW" & sr), order1:=1
    End With
  Next Area
End With
Application.ScreenUpdating = True
End Sub

With the same instructions from the first macro.

Then run the kapperson_V2 macro.
 
Upvote 0
Thank you so much, I really appreciate your help!

It looks like it's only sorting that column, so I changed the line

Code:
Range("DW" & sr & ":DW" & er).Sort key1:=Range("DW" & sr), order1:=1

to

Code:
Range("DW" & sr & ":DW" & er).EntireRow.Sort key1:=Range("DW" & sr), order1:=1

and that seems to sort the entire row.

For some reason when I apply to my spreadsheet, though, it puts one row above the header. Do you know why that might be?
 
Upvote 0
Thank you so much, I really appreciate your help!

It looks like it's only sorting that column, so I changed the line

Code:
Range("DW" & sr & ":DW" & er).Sort key1:=Range("DW" & sr), order1:=1


to

Code:
Range("DW" & sr & ":DW" & er).EntireRow.Sort key1:=Range("DW" & sr), order1:=1

and that seems to sort the entire row.

For some reason when I apply to my spreadsheet, though, it puts one row above the header. Do you know why that might be?

Hi hiker95,
It looks like the problem was that my worksheet was using formulas instead of actual values. As a workaround I coded to copy and paste values into column DZ and sorted by that, so that it could read them as true values.
The only problem I'm having now is that it's including the value in the total row in the sort, so my total row ends up in the middle of the table. Any thoughts on how to get around that?

Thank you so much!!

Here's my revised code for your reference:

Code:
Sub kapperson_V2()' hiker95, 07/06/2017, ME1012860
Columns("DZ:DZ").Select
    Selection.Insert Shift:=xlToRight, CopyOrigin:=xlFormatFromLeftOrAbove
Columns("DW:DW").Copy
Range("DZ1").PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, _
        SkipBlanks:=False, Transpose:=False


Dim Area As Range, sr As Long, er As Long
Application.ScreenUpdating = False
With ActiveSheet
  For Each Area In Range("DZ1", Range("DZ" & .Rows.Count).End(xlUp)).SpecialCells(xlCellTypeConstants).Areas
    With Area
      sr = .Row + 1
      er = sr + .Rows.Count - 2
      Range("DZ" & sr & ":DZ" & er).EntireRow.Sort key1:=Range("DZ" & sr), order1:=1
    End With
  Next Area
End With
Application.ScreenUpdating = True
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,911
Messages
6,175,327
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