Home |
Search |
Today's Posts |
#1
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
I need to sort columns of data, but in batches on the same worksheet.
e.g. There will always be a heading on row 1, followed by a sub-heading on row. Then follows data on rows 3 - 10. Finally, a blank line (row 11). In this example the next batch of data commences on row 12 (heading) and row 13 (sub-heading), followed by 13 lines of data (rows 14 - 25). As above, a blank line finishes the sequence on row 26. 1 Heading 2 Sub-heading 3 Data 4 Data 5 Data 6 Data 7 Data 8 Data 9 Data 10 Data 11 Blank 12 Heading 13 Sub-heading 14 Data 15 Data 16 Data 17 Data 18 Data 19 Data 20 Data 21 Data 22 Data 23 Data 24 Data 25 Data 26 Blank The data part of the worksheet always varies, which is my problem. Data can be anything from 1 to 40 lines. Could some code be created which would recognise the blank line and sort each batch of data by a chosen column? The data represents horses in a race, which varies from day to day. |
#3
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Maybe...
Is your data in column A text or formulas? Are those blanks really empty cells? If you column A contains Text and those are really empty cells in column A, you could try this: Option Explicit Sub testme() Dim myRngToSort As Range Dim myBigRng As Range Dim myPiecesRng As Range Dim myArea As Range Dim wks As Worksheet Dim TotalColsToSort As Long Dim KeyCol As Long Set wks = Worksheets("sheet1") With wks TotalColsToSort = 12 KeyCol = 1 Set myBigRng = .Range("a1", .Cells(.Rows.Count, "A").End(xlUp)) Set myPiecesRng = Nothing On Error Resume Next Set myPiecesRng = myBigRng.Cells.SpecialCells(xlCellTypeConstants) On Error GoTo 0 If myPiecesRng Is Nothing Then MsgBox "No constants in column A!" Exit Sub End If For Each myArea In myPiecesRng.Areas With myArea 'come down 2 rows to avoid the headings Set myRngToSort _ = .Resize(.Rows.Count - 2, TotalColsToSort).Offset(2, 0) myRngToSort.Sort key1:=.Columns(1), order1:=xlAscending, _ header:=xlNo End With Next myArea End With End Sub I sorted A:L (that's what "TotalColsToSort = 12" did). And I sorted by column A (KeyCol = 1). If you're new to macros, you may want to read David McRitchie's intro at: http://www.mvps.org/dmcritchie/excel/getstarted.htm Saxman wrote: I need to sort columns of data, but in batches on the same worksheet. e.g. There will always be a heading on row 1, followed by a sub-heading on row. Then follows data on rows 3 - 10. Finally, a blank line (row 11). In this example the next batch of data commences on row 12 (heading) and row 13 (sub-heading), followed by 13 lines of data (rows 14 - 25). As above, a blank line finishes the sequence on row 26. 1 Heading 2 Sub-heading 3 Data 4 Data 5 Data 6 Data 7 Data 8 Data 9 Data 10 Data 11 Blank 12 Heading 13 Sub-heading 14 Data 15 Data 16 Data 17 Data 18 Data 19 Data 20 Data 21 Data 22 Data 23 Data 24 Data 25 Data 26 Blank The data part of the worksheet always varies, which is my problem. Data can be anything from 1 to 40 lines. Could some code be created which would recognise the blank line and sort each batch of data by a chosen column? The data represents horses in a race, which varies from day to day. -- Dave Peterson |
#4
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Dave Peterson wrote:
Maybe... Is your data in column A text or formulas? Are those blanks really empty cells? There are no formulas within the worksheet, just numbers and text. The blank cells are completely empty. Thanks. |
#5
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Saxman wrote:
There are no formulas within the worksheet, just numbers and text. The blank cells are completely empty. I ought to add that when I import the data into a worksheet, column 'L' is already sorted. I then rank the data from column 'L', 1 to whatever for simplicity. I then sort columns 'J' and 'K' and do similar. I was hoping to make a start with the code you have provided and then to create a macro with the other bits to do the numbering added on later. I need to know how to sort other columns with the code provided. Thanks again for your help. |
#6
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Dave,
And I sorted by column A (KeyCol = 1). You don't actually seem to use KeyCol in you code, just DIM it and assign it. -- HTH Sandy In Perth, the ancient capital of Scotland and the crowning place of kings with @tiscali.co.uk "Dave Peterson" wrote in message ... Maybe... Is your data in column A text or formulas? Are those blanks really empty cells? If you column A contains Text and those are really empty cells in column A, you could try this: Option Explicit Sub testme() Dim myRngToSort As Range Dim myBigRng As Range Dim myPiecesRng As Range Dim myArea As Range Dim wks As Worksheet Dim TotalColsToSort As Long Dim KeyCol As Long Set wks = Worksheets("sheet1") With wks TotalColsToSort = 12 KeyCol = 1 Set myBigRng = .Range("a1", .Cells(.Rows.Count, "A").End(xlUp)) Set myPiecesRng = Nothing On Error Resume Next Set myPiecesRng = myBigRng.Cells.SpecialCells(xlCellTypeConstants) On Error GoTo 0 If myPiecesRng Is Nothing Then MsgBox "No constants in column A!" Exit Sub End If For Each myArea In myPiecesRng.Areas With myArea 'come down 2 rows to avoid the headings Set myRngToSort _ = .Resize(.Rows.Count - 2, TotalColsToSort).Offset(2, 0) myRngToSort.Sort key1:=.Columns(1), order1:=xlAscending, _ header:=xlNo End With Next myArea End With End Sub I sorted A:L (that's what "TotalColsToSort = 12" did). And I sorted by column A (KeyCol = 1). If you're new to macros, you may want to read David McRitchie's intro at: http://www.mvps.org/dmcritchie/excel/getstarted.htm Saxman wrote: I need to sort columns of data, but in batches on the same worksheet. e.g. There will always be a heading on row 1, followed by a sub-heading on row. Then follows data on rows 3 - 10. Finally, a blank line (row 11). In this example the next batch of data commences on row 12 (heading) and row 13 (sub-heading), followed by 13 lines of data (rows 14 - 25). As above, a blank line finishes the sequence on row 26. 1 Heading 2 Sub-heading 3 Data 4 Data 5 Data 6 Data 7 Data 8 Data 9 Data 10 Data 11 Blank 12 Heading 13 Sub-heading 14 Data 15 Data 16 Data 17 Data 18 Data 19 Data 20 Data 21 Data 22 Data 23 Data 24 Data 25 Data 26 Blank The data part of the worksheet always varies, which is my problem. Data can be anything from 1 to 40 lines. Could some code be created which would recognise the blank line and sort each batch of data by a chosen column? The data represents horses in a race, which varies from day to day. -- Dave Peterson |
#7
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
I declared a variable named keycol--I meant to use that in the sort routine.
But you can specify up to 3 keys in your sort. I used keycol1, keycol2, and keycol3. I wasn't sure when/what you sorted. But this line: myRngToSort.Sort _ key1:=.Columns(KeyCol1), order1:=xlAscending, _ key2:=.Columns(KeyCol2), order1:=xlAscending, _ key3:=.Columns(KeyCol3), order1:=xlAscending, _ header:=xlNo is the line that does all the real work for each group of data. Option Explicit Sub testme() Dim myRngToSort As Range Dim myBigRng As Range Dim myPiecesRng As Range Dim myArea As Range Dim wks As Worksheet Dim TotalColsToSort As Long Dim KeyCol1 As Long Dim KeyCol2 As Long Dim KeyCol3 As Long Set wks = Worksheets("sheet1") With wks TotalColsToSort = 12 KeyCol1 = 10 'column j KeyCol2 = 11 'column k KeyCol3 = 1 'column A Set myBigRng = .Range("a1", .Cells(.Rows.Count, "A").End(xlUp)) Set myPiecesRng = Nothing On Error Resume Next Set myPiecesRng = myBigRng.Cells.SpecialCells(xlCellTypeConstants) On Error GoTo 0 If myPiecesRng Is Nothing Then MsgBox "No constants in column A!" Exit Sub End If For Each myArea In myPiecesRng.Areas With myArea 'come down 2 rows to avoid the headings Set myRngToSort _ = .Resize(.Rows.Count - 2, TotalColsToSort).Offset(2, 0) myRngToSort.Sort _ key1:=.Columns(KeyCol1), order1:=xlAscending, _ key2:=.Columns(KeyCol2), order1:=xlAscending, _ key3:=.Columns(KeyCol3), order1:=xlAscending, _ header:=xlNo End With Next myArea End With End Sub Saxman wrote: Saxman wrote: There are no formulas within the worksheet, just numbers and text. The blank cells are completely empty. I ought to add that when I import the data into a worksheet, column 'L' is already sorted. I then rank the data from column 'L', 1 to whatever for simplicity. I then sort columns 'J' and 'K' and do similar. I was hoping to make a start with the code you have provided and then to create a macro with the other bits to do the numbering added on later. I need to know how to sort other columns with the code provided. Thanks again for your help. -- Dave Peterson |
#8
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Yep. I wasn't sure how many columns to sort or what column to sort by. I
created a couple of variables and adjusted the code for the number of columns but forgot the key column (something shiny distracted me!). But I did use them in the followup! Sandy Mann wrote: Dave, And I sorted by column A (KeyCol = 1). You don't actually seem to use KeyCol in you code, just DIM it and assign it. -- HTH Sandy In Perth, the ancient capital of Scotland and the crowning place of kings with @tiscali.co.uk "Dave Peterson" wrote in message ... Maybe... Is your data in column A text or formulas? Are those blanks really empty cells? If you column A contains Text and those are really empty cells in column A, you could try this: Option Explicit Sub testme() Dim myRngToSort As Range Dim myBigRng As Range Dim myPiecesRng As Range Dim myArea As Range Dim wks As Worksheet Dim TotalColsToSort As Long Dim KeyCol As Long Set wks = Worksheets("sheet1") With wks TotalColsToSort = 12 KeyCol = 1 Set myBigRng = .Range("a1", .Cells(.Rows.Count, "A").End(xlUp)) Set myPiecesRng = Nothing On Error Resume Next Set myPiecesRng = myBigRng.Cells.SpecialCells(xlCellTypeConstants) On Error GoTo 0 If myPiecesRng Is Nothing Then MsgBox "No constants in column A!" Exit Sub End If For Each myArea In myPiecesRng.Areas With myArea 'come down 2 rows to avoid the headings Set myRngToSort _ = .Resize(.Rows.Count - 2, TotalColsToSort).Offset(2, 0) myRngToSort.Sort key1:=.Columns(1), order1:=xlAscending, _ header:=xlNo End With Next myArea End With End Sub I sorted A:L (that's what "TotalColsToSort = 12" did). And I sorted by column A (KeyCol = 1). If you're new to macros, you may want to read David McRitchie's intro at: http://www.mvps.org/dmcritchie/excel/getstarted.htm Saxman wrote: I need to sort columns of data, but in batches on the same worksheet. e.g. There will always be a heading on row 1, followed by a sub-heading on row. Then follows data on rows 3 - 10. Finally, a blank line (row 11). In this example the next batch of data commences on row 12 (heading) and row 13 (sub-heading), followed by 13 lines of data (rows 14 - 25). As above, a blank line finishes the sequence on row 26. 1 Heading 2 Sub-heading 3 Data 4 Data 5 Data 6 Data 7 Data 8 Data 9 Data 10 Data 11 Blank 12 Heading 13 Sub-heading 14 Data 15 Data 16 Data 17 Data 18 Data 19 Data 20 Data 21 Data 22 Data 23 Data 24 Data 25 Data 26 Blank The data part of the worksheet always varies, which is my problem. Data can be anything from 1 to 40 lines. Could some code be created which would recognise the blank line and sort each batch of data by a chosen column? The data represents horses in a race, which varies from day to day. -- Dave Peterson -- Dave Peterson |
#9
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Dave Peterson wrote:
I declared a variable named keycol--I meant to use that in the sort routine. But you can specify up to 3 keys in your sort. I used keycol1, keycol2, and keycol3. I wasn't sure when/what you sorted. But this line: myRngToSort.Sort _ key1:=.Columns(KeyCol1), order1:=xlAscending, _ key2:=.Columns(KeyCol2), order1:=xlAscending, _ key3:=.Columns(KeyCol3), order1:=xlAscending, _ header:=xlNo This sorts column 'J' ascending. Ideally I would like it descending. I assume I can alter the code to descending in the above? How do I need to modify the code to do a sort on column 'K'? Once 'J' has been sorted ascending would it be possible to rank them 1,2,3, etc. in column 'N'. I would need to do the same for column 'O' and rank them in column 'P'. As I said before the data is imported with column 'L' already sorted. These would need ranking in column 'P'. Maybe I could send a sample sheet to you? Thanks for you time and tenacity. |
#10
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Saxman wrote:
myRngToSort.Sort _ key1:=.Columns(KeyCol1), order1:=xlAscending, _ key2:=.Columns(KeyCol2), order1:=xlAscending, _ key3:=.Columns(KeyCol3), order1:=xlAscending, _ header:=xlNo This sorts column 'J' ascending. Ideally I would like it descending. I assume I can alter the code to descending in the above? I've replaced the above with descending and column 'J' sorts fine. Once 'J' has been sorted ascending would it be possible to rank them 1,2,3, etc. in column 'N'. By this I meant the AutoFill function and FillSeries. |
#11
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
How about:
Option Explicit Sub testme() Dim myRngToSort As Range Dim myBigRng As Range Dim myPiecesRng As Range Dim myArea As Range Dim wks As Worksheet Dim TotalColsToSort As Long Dim KeyCol1 As Long Dim KeyCol2 As Long Dim KeyCol3 As Long Dim ColThatGetsRanked As Long Set wks = Worksheets("sheet1") With wks TotalColsToSort = 12 KeyCol1 = 10 'column j KeyCol2 = 11 'column k KeyCol3 = 1 'column A ColThatGetsRanked = .Range("n1").Column Set myBigRng = .Range("a1", .Cells(.Rows.Count, "A").End(xlUp)) Set myPiecesRng = Nothing On Error Resume Next Set myPiecesRng = myBigRng.Cells.SpecialCells(xlCellTypeConstants) On Error GoTo 0 If myPiecesRng Is Nothing Then MsgBox "No constants in column A!" Exit Sub End If For Each myArea In myPiecesRng.Areas With myArea 'come down 2 rows to avoid the headings Set myRngToSort _ = .Resize(.Rows.Count - 2, TotalColsToSort).Offset(2, 0) myRngToSort.Sort _ key1:=.Columns(KeyCol1), order1:=xlDescending, _ key2:=.Columns(KeyCol2), order1:=xlDescending, _ key3:=.Columns(KeyCol3), order1:=xlDescending, _ header:=xlNo With myRngToSort.Resize(, 1).Offset(0, ColThatGetsRanked - 1) .Formula = "=row()+1-" & myRngToSort.Row .Value = .Value End With End With Next myArea End With End Sub Saxman wrote: Saxman wrote: myRngToSort.Sort _ key1:=.Columns(KeyCol1), order1:=xlAscending, _ key2:=.Columns(KeyCol2), order1:=xlAscending, _ key3:=.Columns(KeyCol3), order1:=xlAscending, _ header:=xlNo This sorts column 'J' ascending. Ideally I would like it descending. I assume I can alter the code to descending in the above? I've replaced the above with descending and column 'J' sorts fine. Once 'J' has been sorted ascending would it be possible to rank them 1,2,3, etc. in column 'N'. By this I meant the AutoFill function and FillSeries. -- Dave Peterson |
#12
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Dave Peterson wrote:
How about: Option Explicit Sub testme() Dim myRngToSort As Range Dim myBigRng As Range Dim myPiecesRng As Range Dim myArea As Range Dim wks As Worksheet Dim TotalColsToSort As Long Dim KeyCol1 As Long Dim KeyCol2 As Long Dim KeyCol3 As Long Dim ColThatGetsRanked As Long That is perfect! It sorts column 'J' and fills down in column 'N' in batches. After I have run the above, how can I get it to sort column 'K' and filldown in column 'O' and then sort column 'L' and filldown in column 'P' similarly? |
#13
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
You can make additional macros.
This will be the area you want to change: TotalColsToSort = 12 KeyCol1 = 10 'column j KeyCol2 = 11 'column k KeyCol3 = 1 'column A ColThatGetsRanked = .Range("n1").Column Saxman wrote: Dave Peterson wrote: How about: Option Explicit Sub testme() Dim myRngToSort As Range Dim myBigRng As Range Dim myPiecesRng As Range Dim myArea As Range Dim wks As Worksheet Dim TotalColsToSort As Long Dim KeyCol1 As Long Dim KeyCol2 As Long Dim KeyCol3 As Long Dim ColThatGetsRanked As Long That is perfect! It sorts column 'J' and fills down in column 'N' in batches. After I have run the above, how can I get it to sort column 'K' and filldown in column 'O' and then sort column 'L' and filldown in column 'P' similarly? -- Dave Peterson |
#14
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Or you could just do all the sorts at once:
Option Explicit Sub testme() Dim myRngToSort As Range Dim myBigRng As Range Dim myPiecesRng As Range Dim myArea As Range Dim wks As Worksheet Dim TotalColsToSort As Long Dim KeyCol1 As Variant Dim KeyCol2 As Variant Dim KeyCol3 As Variant Dim ColThatGetsRanked As Variant Dim iCtr As Long Set wks = Worksheets("sheet1") With wks 'fix this part to sort what you want and by what you want TotalColsToSort = 20 KeyCol1 = Array(10, 11, 12) KeyCol2 = Array(11, 12, 13) KeyCol3 = Array(1, 1, 1) 'fix this part to add the rankings to the correct columns ColThatGetsRanked = Array(14, 15, 16) Set myBigRng = .Range("a1", .Cells(.Rows.Count, "A").End(xlUp)) Set myPiecesRng = Nothing On Error Resume Next Set myPiecesRng = myBigRng.Cells.SpecialCells(xlCellTypeConstants) On Error GoTo 0 If myPiecesRng Is Nothing Then MsgBox "No constants in column A!" Exit Sub End If For Each myArea In myPiecesRng.Areas With myArea 'come down 2 rows to avoid the headings Set myRngToSort _ = .Resize(.Rows.Count - 2, TotalColsToSort).Offset(2, 0) For iCtr = LBound(KeyCol1) To UBound(KeyCol1) myRngToSort.Sort _ key1:=.Columns(KeyCol1(iCtr)), order1:=xlDescending, _ key2:=.Columns(KeyCol2(iCtr)), order1:=xlDescending, _ key3:=.Columns(KeyCol3(iCtr)), order1:=xlDescending, _ header:=xlNo With myRngToSort.Resize(, 1) _ .Offset(0, ColThatGetsRanked(iCtr) - 1) .Formula = "=row()+1-" & myRngToSort.Row .Value = .Value End With Next iCtr End With Next myArea End With End Sub Dave Peterson wrote: You can make additional macros. This will be the area you want to change: TotalColsToSort = 12 KeyCol1 = 10 'column j KeyCol2 = 11 'column k KeyCol3 = 1 'column A ColThatGetsRanked = .Range("n1").Column Saxman wrote: Dave Peterson wrote: How about: Option Explicit Sub testme() Dim myRngToSort As Range Dim myBigRng As Range Dim myPiecesRng As Range Dim myArea As Range Dim wks As Worksheet Dim TotalColsToSort As Long Dim KeyCol1 As Long Dim KeyCol2 As Long Dim KeyCol3 As Long Dim ColThatGetsRanked As Long That is perfect! It sorts column 'J' and fills down in column 'N' in batches. After I have run the above, how can I get it to sort column 'K' and filldown in column 'O' and then sort column 'L' and filldown in column 'P' similarly? -- Dave Peterson -- Dave Peterson |
#15
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Dave Peterson wrote:
Or you could just do all the sorts at once: That works beautifully! Exactly what I wanted. I can do another macro for calculations and combine them into one. I see that you are a 'dab hand' at this kind of thing during my searches. I do have a good book on Excel VBA, but books usually cover common things like formatting. I am most grateful to you. John (Essex, UK). |
#16
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Glad you got it working the way you want.
Saxman wrote: Dave Peterson wrote: Or you could just do all the sorts at once: That works beautifully! Exactly what I wanted. I can do another macro for calculations and combine them into one. I see that you are a 'dab hand' at this kind of thing during my searches. I do have a good book on Excel VBA, but books usually cover common things like formatting. I am most grateful to you. John (Essex, UK). -- Dave Peterson |
#17
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
PS. You may want to look at =rank(). You wouldn't have to even sort the data
to do the ranking. Dave Peterson wrote: Glad you got it working the way you want. Saxman wrote: Dave Peterson wrote: Or you could just do all the sorts at once: That works beautifully! Exactly what I wanted. I can do another macro for calculations and combine them into one. I see that you are a 'dab hand' at this kind of thing during my searches. I do have a good book on Excel VBA, but books usually cover common things like formatting. I am most grateful to you. John (Essex, UK). -- Dave Peterson -- Dave Peterson |
#18
![]()
Posted to microsoft.public.excel.misc
|
|||
|
|||
![]()
Dave Peterson wrote:
PS. You may want to look at =rank(). You wouldn't have to even sort the data to do the ranking. Thanks again. I really ought to look at the archives of the group and learn a bit more. It is probably the most valuable resource. |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
Sorting Sorting Sorting | Excel Discussion (Misc queries) | |||
Sorting | New Users to Excel | |||
Advice sought: Multiple column sorting | Excel Worksheet Functions | |||
Sorting 1, 1A, 2, 2A, 3, 4, 4A, 4B . . . | Excel Discussion (Misc queries) | |||
Adding a KeyID column for sorting | New Users to Excel |