At 11:17 07/06/2013 -0400, Charles Marcus wrote:
I have a workbook with multiple sheets, some of which reference data
from other sheets in the workbook. I have one 'Main' sheet, that
lists our Sales Reps, and has each ones monthly numbers, by column, ie:
1 Name Jan Feb ... Dec YTD
2 Rep1 ### ### ### ### ###
3 Rep2 ### ### ### ### ###
I have other sheets that have these Reps broken down by Team, and
pulling each Reps numbers from the Main sheet. The problem is, I
need to be able to sort the Main Sheet by the Sum column (to show
the top Sales Rep), but when I do that, since the references on the
Team sheets still reference the same Col/Row, the numbers are now
wrong. Googling reveals this is apparently by design, as the Rows
themselves aren't changing.
One workaround for this would be to use VLOOKUP() to extract the
information from your Main sheet to the others instead of addressing
cells directly. The names - Rep1 and so on - would naturally appear
on your later sheets, and the cell in which they appear should be the
first parameter of your VLOOKUP() there. The second parameter would
be the array of values on the Main sheet, the third indicate
(numerically) which column of data (month etc.) you wish to retrieve,
and the fourth FALSE or zero, to indicate that the key "Name" column
in the array is not necessarily sorted. The values would now be
found irrespective of the ordering within your source array on the Main sheet.
So, I was think if I could reference it instead of by Row#, by the
content of A# - ie, instead of: 'Main.A2' for the Jan numbers for
Rep1, something like: 'Main.A"Rep1"'. Is this possible?
That's effectively what VLOOKUP() does, of course.
There is a way of doing something like this, using the INDIRECT()
function: =INDIRECT("Main.A"&<expression>) will reference a cell in
column C on sheet Main according to the numeric value of <expression>
(which could be just a cell reference, of course). But I suspect
that this is of little use here, as extracting the relevant number to
use is probably the same as the original problem.
I trust this helps.
Brian Barker
--
To unsubscribe e-mail to: users+unsubscribe@global.libreoffice.org
Problems? http://www.libreoffice.org/get-help/mailing-lists/how-to-unsubscribe/
Posting guidelines + more: http://wiki.documentfoundation.org/Netiquette
List archive: http://listarchives.libreoffice.org/global/users/
All messages sent to this list will be publicly archived and cannot be deleted
Context
Privacy Policy |
Impressum (Legal Info) |
Copyright information: Unless otherwise specified, all text and images
on this website are licensed under the
Creative Commons Attribution-Share Alike 3.0 License.
This does not include the source code of LibreOffice, which is
licensed under the Mozilla Public License (
MPLv2).
"LibreOffice" and "The Document Foundation" are
registered trademarks of their corresponding registered owners or are
in actual use as trademarks in one or more countries. Their respective
logos and icons are also subject to international copyright laws. Use
thereof is explained in our
trademark policy.