Sorting Data Without changing formulas

Jonmo1

MrExcel MVP
Joined
Oct 12, 2006
Messages
44,061
Ok, I'm new here this is my first post.

I'm using just an example of my problem, not the real data of coarse.
Sheet 1 collumn A contains data manually entered by a user.
Sheet 2 collumn A has formulas referenceing Sheet 1 Collumn A
Sheet 1 collumn C has formulas referencing the results of the formulas in Sheet 2 Collumn A.

There are of coarse other data in collumns B,D,E etc in Sheet 1.
When I sort all collumns in Sheet 1, the formulas in Collumn C change with it. Since the formulas in Sheet 2 Collumn A do NOT get changed when sorting Sheet 1, this makes the formulas in Sheet 1 Collumn C invalid.

How can I correct this?

Any help would be great
 

Excel Facts

Return population for a City
If you have a list of cities in A2:A100, use Data, Geography. Then =A2.Population and copy down.
Why not copy Sheet2, Column A to Sheet 1, in the range you sort? Then, after doing the sort, you could re-copy the sorted column back to Sheet2. You can easily record a macro to do this, I believe.
 
Upvote 0
Thanks, I had thought of a macro. I could probably make a macro that Corrects the formulas in sheet 1, I would really just have to correct the Cell Reference in the top formula, and fill down. But I was hoping to do it without a macro, or having depend on the user to do extra work - you know users right.

I'm really just hoping to find a way to do either of 2 things, 1, Exclude collumn C from a Sort that includes Collumns A through D+. Or 2, Somehow Lock the formulas in Collumn C so they don't get sorted with the rest of the collumns. When I use the Locked feature in sheet protection, it won't let me sort anymore, even after choosing the allow sort option.

I'm just looking to see if this can be done, for future reference as well as for my current problem.

The macro will probably work for the current problem, but How would I trigger the macro to run automatically when a user sorts? So I don't have to depend on the user doing it.

Thanks again.
 
Upvote 0
Hi,jonmo1
Welcome to the Board !!!!

would this summarize your problem ?

START WITH these sheets
  A      B  C      
1 header    header 
2 D         D      
3 C         C      
4 A         A      
5 B         B      
6 E         E      

sheet1

[Table-It] version 06 by Erik Van Geit
Code:
RANGE FORMULA (1st cell)
C2:C6 =sheet2!A2

[Table-It] version 06 by Erik Van Geit

  A      
1 header 
2 D      
3 C      
4 A      
5 B      
6 E      

sheet2

[Table-It] version 06 by Erik Van Geit
Code:
RANGE FORMULA (1st cell)
A2:A6 =sheet1!A2

[Table-It] version 06 by Erik Van Geit

SORTING ROWS 2 to 6, you get
  A      B  C      
1 header    header 
2 A         C      
3 B         D      
4 C         B      
5 D         A      
6 E         E      

sheet1

[Table-It] version 06 by Erik Van Geit
Code:
RANGE FORMULA (1st cell)
C2    =sheet2!A4
C3    =sheet2!A5
C4    =sheet2!A3
C5    =sheet2!A2
C6    =sheet2!A6

[Table-It] version 06 by Erik Van Geit
this is NOT what you want

WOULD THIS BE a solution ?
in C2 =INDIRECT("sheet2!A" & ROW())
copied down

check out on this example before trying to adapt to your situation

kind regards,
Erik
 
Upvote 0
Thanks

The Indirect function worked perfectly. Thanks. I had seen that function before and tried it, but I couldn't make it work. What did the trick was not specifying row # in the formula. When I did it myself before, I specified row # in the formula and it still got sorted with everything else.

Thanks again for the help.
 
Upvote 0
Eric:

Nice, clear thinking! I hope I learn to think better, from your example.
 
Upvote 0
Oh, no, Eric! I won't be that old until the 26th of this month! Ha, ha. How about you?
 
Upvote 0
Eric,
I am trying to understand the reasoning behind this. When you use the indirect and sort all columns in sheet 1, in column C, you get exactly what is in column A. Is this what was desired? I am not understanding the problem, but I want ot understand the solution. If you have the time of course. :)
 
Upvote 0

Forum statistics

Threads
1,213,524
Messages
6,114,117
Members
448,549
Latest member
brianhfield

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