Change column order

Andy0311

Board Regular
Joined
Oct 16, 2019
Messages
118
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
Hello,

Shown below is a simple table showing a list of students and their grades for tests they periodically take. I send the results to them so that they can see how everyone is performing without knowing each others scores. I would like to automatically anonymise the columns each time I send the results so that the students won't be in the same position as last time. I need some advice on how to approach this. Thank you.

Andy


Share the table with out the first row with the group initially
Actual NameAndyBrianJaneMikeSueTom
Identifier #123456
Test 18598100738895
Test 29091100848589
Test 390100100879287
Average88.396.3100.081.388.390.3
Share the table except for the first row with the group subsequently with column order changed
Actual NameBrianJaneAndySueMikeTom
Identifier #123456
Test 19810085887395
Test 29110090858489
Test 310010090928787
Average96.3100.088.388.381.390.3

<colgroup><col><col span="9"></colgroup><tbody>
</tbody>

Desired Result to be able to change the column order each time I send the report out
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
There are lots of ways to do this, formulas or VBA. Here's a formula option.


Book1
ABCDEFGHIJKLMN
1Actual NameAndyBrianJaneMikeSueTom0.1725512950.527810.26640.619430.11128
2Identifier #12345642315
3Test 18598100738895Test 173981008588
4Test 29091100848589Test 284911009085
5Test 390100100879287Test 3871001009092
6Average88.396.310081.388.390.3Average81.396.310088.388.3
Sheet4
Cell Formulas
RangeFormula
J1=RAND()
J2=RANK(J1,$J$1:$N$1)
J3=INDEX($B:$G,ROW(),J$2)


Put the J1 and J2 formulas in and copy them to the right as far as needed. Put the J3 formula in and copy right and down as needed. The columns will be randomized every time you make a change to the sheet. You can just press F9 to recalculate them too.
 
Upvote 0
There are lots of ways to do this, formulas or VBA. Here's a formula option.

ABCDEFGHIJKLMN
1Actual NameAndyBrianJaneMikeSueTom0.1725512950.527810.26640.619430.11128
2Identifier #12345642315
3Test 18598100738895Test 173981008588
4Test 29091100848589Test 284911009085
5Test 390100100879287Test 3871001009092
6Average88.396.310081.388.390.3Average81.396.310088.388.3

<tbody>
</tbody>
Sheet4

Worksheet Formulas
CellFormula
J1=RAND()
J2=RANK(J1,$J$1:$N$1)
J3=INDEX($B:$G,ROW(),J$2)

<tbody>
</tbody>

<tbody>
</tbody>



Put the J1 and J2 formulas in and copy them to the right as far as needed. Put the J3 formula in and copy right and down as needed. The columns will be randomized every time you make a change to the sheet. You can just press F9 to recalculate them too.

Thanks, Eric. Great help. I really appreciate it. Andy
 
Upvote 0
Thanks, Eric. Great help. I really appreciate it. Andy
Question: Did you always want to keep the same Identifier # associated with their same scores the way Eric's solution does? I ask because your original post seemed to disassociate the Identifier # from the names and scores.
 
Upvote 0
Question: Did you always want to keep the same Identifier # associated with their same scores the way Eric's solution does? I ask because your original post seemed to disassociate the Identifier # from the names and scores.
Here is a VBA macro that will randomly mix your columns...
Code:
Sub RandomizeStudentColumns()
  Dim Cnt As Long, RndIndx As Long, Cols As Variant, Tmp As Variant
  Cols = [TRANSPOSE(ROW(2:7))]
  For Cnt = 6 To 1 Step -1
    RndIndx = [RANDBETWEEN(1,6)]
    Tmp = Cols(RndIndx)
    Cols(RndIndx) = Cols(Cnt)
    Cols(Cnt) = Tmp
  Next
  Range("B1", Cells(Rows.Count, "G").End(xlUp)) = Application.Index(Cells, [ROW(1:6)], Cols)
  [B][COLOR="#FF0000"]Range("B2:G2") = [{1,2,3,4,5,6}][/COLOR][/B]
End Sub
This code keeps the Identifier #'s in the order 1, 2, 3, 4, 5, 6 as your original post shows. If you want the Identifier # to move with the names the way Eric's formula solution does, then simply remove the line of code I show in red.
 
Upvote 0
Question: Did you always want to keep the same Identifier # associated with their same scores the way Eric's solution does? I ask because your original post seemed to disassociate the Identifier # from the names and scores.

Yes, I did. Students will look at the group report and often times email me, and ask,"What student am I in the report?" That way a student whose identifier is #3 will always be #3 . His or her column position, however, may be different. Thanks for the feedback, Rick.

Andy
 
Upvote 0
Thank you so much, Rick. I will save and try this out. I appreciate your input.

Andy
 
Upvote 0
Thank you so much, Rick. I will save and try this out. I appreciate your input.
It occurs to me that you may give more tests later on and, in the future, you may have more or less students, so here is my code fully generalized so that it will adapt automatically to the number of students and the number of test shown on the worksheet (that way you will be able to use this for any of your classes, either now or in the future)...
Code:
Sub RandomizeStudentColumns()
  Dim Cnt As Long, RndIndx As Long, NumberOfStudents As Long, LastRow As Long, Cols As Variant, Tmp As Variant
  NumberOfStudents = Cells(1, Columns.Count).End(xlToLeft).Column - 1
  LastRow = Cells(Rows.Count, "A").End(xlUp).Row
  Cols = Evaluate("TRANSPOSE(ROW(2:" & NumberOfStudents + 1 & "))")
  For Cnt = UBound(Cols) To 1 Step -1
    RndIndx = Evaluate("RANDBETWEEN(1," & UBound(Cols) & ")")
    Tmp = Cols(RndIndx)
    Cols(RndIndx) = Cols(Cnt)
    Cols(Cnt) = Tmp
  Next
  Range("B1:G" & LastRow) = Application.Index(Cells, Evaluate("ROW(1:" & LastRow & ")"), Cols)
End Sub
Just run the code whenever you want to randomly mix the student columns around. Easiest would be to put a Form's Button on the worksheet and assign my code as the macro for that button, then all you have to do is click the button to mix the columns (you may want to do this several times is the random number generator does not move all of the columns from their current location).
 
Last edited:
Upvote 0

Forum statistics

Threads
1,213,543
Messages
6,114,240
Members
448,555
Latest member
RobertJones1986

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