[mso] Re: Unsolicited Sharing - Relative Incrementing of the INDIRECT formula

  • From: "David Smart" <smartware@xxxxxxxxxxxxxxx>
  • To: <mso@xxxxxxxxxxxxx>
  • Date: Fri, 23 Jun 2006 21:26:19 +1000

Shirley

That's a nice way to do what you wanted, and also has the distinct advantage 
of being done at "compile time".  I.e. the resulting formulas are as 
efficient as you're going to get them.

Another trick I've used on occasion - particularly when I'm only working 
with a single column - is to put local cell references in the formulas and 
then extract the row numbers from them.  For instance, if I put the 
following in G1:

  =INDIRECT("Sheet2!B"&ROW(G1))

This will produce an indirect of B1 in sheet 2.  This formula can be copied 
downwards and will sort itself out on other rows.

It is possible to do the same thing in such a way that it can be copied 
across the sheet too.  E.g.

  =INDIRECT("Sheet2!R"&ROW(G1)&"C"&COLUMN(G1),FALSE)

The FALSE takes the INDIRECT call into R1C1 mode so you can supply it with 
column numbers rather than letters.  The above formula grabs the G1 cell out 
of Sheet 2.  If you put the formula in G1, it can then be copied anywhere on 
the sheet and will return the corresponding cell from Sheet2.  If you put it 
in a difference cell, it will still return G1 from sheet 2, and copying it 
to other cells will move the selected sheet2 cell relatively.

Obviously, you can also use the $D$1 substitution to vary the sheet name.

The plus side of this method is that it is dynamic.  The minus side is that 
it's all done at "run time" and is relatively slow.  (I certainly wouldn't 
want to use it for the number of cells you're working with.)

(Note that this has the appearance of a circular reference - Cell G1 has a 
reference to itself - but Excel is clever enough not to worry about that.)

Nagging at me also is the suggestion that you can do this with OFFSET.  I'll 
have a play later and post a follow-up if I can work out how.

Regards, Dave S

----- Original Message ----- 
From: "Shirley Graver" <shirleyg@xxxxxxxxxxxxx>
To: <mso@xxxxxxxxxxxxx>
Sent: Friday, June 23, 2006 1:18 AM
Subject: [mso] Unsolicited Sharing - Relative Incrementing of the INDIRECT 
formula


>
> No one has asked about this type of issue that I've seen recently but its
> turned to be such a nice trick I thought I'd share it.
>
> 52 (weeks) spread sheets compiling weekly data, each sheet with 1100 plus
> line items (part numbers, each line item totaling ups 3 values.  Easy to
> bring the total to the summary with   =INDIRECT($D$1&"!G7")  .  However,
> repeat that down 1100 plus lines of data.  Copy and paste will not allow
> "!G7" to perform a relative increment.  Hand edit 1100 formula's  !!yuck!!
> These steps will automate the process.
>
> Step 1 in the indirect formula change from   =INDIRECT($D$1&"!G7")  to
> =INDIRECT($D$1& G7 ),  (you'll get a #ref value in your cell)
>
> Step 2 copy and paste down your range of cells.  (This will allow the G7
> value to increment)
>
> Step 3 Within your copy range, find and replace the "="  with " " (or
> nothing)   INDIRECT($D$1& G7 )    (This changes the line to text, has to 
> be
> text or it will error)
>
> Step 4 Find and replace   &   with &"!  (This changes your text from
> INDIRECT($D$1 & G7) to  INDIRECT($D$1&"!G7)
>
> Step 5 Find and replace ) with ")  (This changes your text from
> INDIRECT($D$1&"!G7) to INDIRECT($D$1&"!G7")
>
> Step 6 Find and Replace  IND  with =IND  which changes your text back to a
> formula  =INDIRECT($D$1&"!G7")
>
>
> If anyone else has tried to deal with this sort of problem hope this 
> helps,
> it's stumped me for a long time.  If there's a better way Please share.
>
> Shirley Graver
> Sys Admin
> Rubber Associates
>
> *************************************************************
> You are receiving this mail because you subscribed to mso@xxxxxxxxxxxxx or 
> MicrosoftOffice@xxxxxxxxxxxxxxxx
>
> To send mail to the group, simply address it to mso@xxxxxxxxxxxxx
>
> To Unsubscribe from this group, visit the group's homepage and use the 
> dropdown menu at the top.  This will allow you to unsubscribe your email 
> address or change your email settings to digest or vacation (no mail).
> //www.freelists.org/webpage/mso
>
> To be able to use the files section for sharing files with the group, send 
> a request to mso-moderators@xxxxxxxxxxxxx and you will be sent an 
> invitation with instructions.  Once you are a member of the files group, 
> you can go here to upload/download files:
> http://www.smartgroups.com/vault/msofiles
>
> If you are using Outlook and you see a lot of unnecessary code in your 
> email messages, read these instructions that explain why and how to fix 
> it:
> http://personal-computer-tutor.com/abc3/v28/greg28.htm
> ************************************************************* 

*************************************************************
You are receiving this mail because you subscribed to mso@xxxxxxxxxxxxx or 
MicrosoftOffice@xxxxxxxxxxxxxxxx

To send mail to the group, simply address it to mso@xxxxxxxxxxxxx

To Unsubscribe from this group, visit the group's homepage and use the dropdown 
menu at the top.  This will allow you to unsubscribe your email address or 
change your email settings to digest or vacation (no mail).
//www.freelists.org/webpage/mso

To be able to use the files section for sharing files with the group, send a 
request to mso-moderators@xxxxxxxxxxxxx and you will be sent an invitation with 
instructions.  Once you are a member of the files group, you can go here to 
upload/download files:
http://www.smartgroups.com/vault/msofiles

If you are using Outlook and you see a lot of unnecessary code in your email 
messages, read these instructions that explain why and how to fix it:
http://personal-computer-tutor.com/abc3/v28/greg28.htm
*************************************************************

Other related posts: