Indirect Sheet References possible? AND Text formatting...

KrisLB

New Member
Joined
Jan 18, 2005
Messages
42
Is there anyway to use indirect sheet references directly in excel rather than creating a macro?

IE: =sheets(1)!A5
And then anytime the sheets are reordered the value of the cell would change.

------
Does anyone know - if possible - make a reference to another cell also identify and model text formatting to that cell?

IE: A5 = "Normal" (1) < (1) in Superscript>
A6 = A5 (would like to maintain the superscripting of "(1)")

-kris
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
Q#1: see this post. (Skip the part on SheetPos and just focus on the part regarding defining wsNames editing the 2nd arg in the call to INDEX() to be just your constant (1 in your example).

Q#2: Only way I can think of without doing a lot of complicated VBA is to copy the cell and hold down your shift key and click on the Edit menu and pick Paste Picture Link from the Shift-Edit menu.
 
Upvote 0
Re: Indirect Sheet References possible? AND Text formattin

Greg, thanks; absolute genius. Works perfectly (re: #1).

(re: #2) I know i can do a normal copy and paste, and that copies cell and text formatting (format painter just copies cell formatting - not text formatting [my assumption is that text formatting is just inserted character codes). I was just wondering if there was a function that would possibly copy text formatting as well as the value.

Appreciate all the help!

-kris
 
Upvote 0
Ok, now I understand what you are after for your question #2. AFAIK, there isn't a built-in tool that will do this for you. However, the following little bit of code seems to work ok for me in testing:

<font face=Courier New><SPAN style="color:#00007F">Sub</SPAN> CopyLetterFormats()
<SPAN style="color:#007F00">' Copies character-level formatting from active cell</SPAN>
<SPAN style="color:#007F00">' to any other selected cells.  So if selecting two</SPAN>
<SPAN style="color:#007F00">' non-contiguous cells/areas, select the targets first</SPAN>
<SPAN style="color:#007F00">' and the source last.      Greg T., Jan 2005</SPAN>

    <SPAN style="color:#00007F">If</SPAN> TypeName(Selection) <> "Range" <SPAN style="color:#00007F">Then</SPAN> <SPAN style="color:#00007F">Exit</SPAN> <SPAN style="color:#00007F">Sub</SPAN>
    
    <SPAN style="color:#00007F">Dim</SPAN> rngSelected <SPAN style="color:#00007F">As</SPAN> Range, rngBaseCell <SPAN style="color:#00007F">As</SPAN> Range, rngCell <SPAN style="color:#00007F">As</SPAN> Range
    <SPAN style="color:#00007F">Dim</SPAN> intLtr <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Integer</SPAN>
    <SPAN style="color:#00007F">Dim</SPAN> fontBase <SPAN style="color:#00007F">As</SPAN> Font
    
    
    <SPAN style="color:#00007F">Set</SPAN> rngBaseCell = ActiveCell
    <SPAN style="color:#00007F">Set</SPAN> rngSelected = Selection
    
    <SPAN style="color:#00007F">If</SPAN> vbNo = MsgBox("Copy letter formats from " & _
                      rngBaseCell.Address(False, False) & _
                      " to the rest of the selected cells?", _
                      vbQuestion + vbYesNo, "Text Format Copy") <SPAN style="color:#00007F">Then</SPAN> <SPAN style="color:#00007F">Exit</SPAN> <SPAN style="color:#00007F">Sub</SPAN>
    
    <SPAN style="color:#00007F">For</SPAN> <SPAN style="color:#00007F">Each</SPAN> rngCell <SPAN style="color:#00007F">In</SPAN> rngSelected
        <SPAN style="color:#00007F">If</SPAN> rngCell.Address = rngBaseCell.Address <SPAN style="color:#00007F">Then</SPAN> <SPAN style="color:#00007F">GoTo</SPAN> EndOfLoop
        <SPAN style="color:#00007F">For</SPAN> intLtr = 1 <SPAN style="color:#00007F">To</SPAN> WorksheetFunction.Min(Len(rngCell.Text), Len(rngBaseCell.Text))
            <SPAN style="color:#00007F">Set</SPAN> fontBase = rngBaseCell.Characters(Start:=intLtr, Length:=1).Font
            <SPAN style="color:#00007F">With</SPAN> rngCell.Characters(Start:=intLtr, Length:=1).Font
                .Name = fontBase.Name
                .FontStyle = fontBase.FontStyle
                .Size = fontBase.Size
                .Strikethrough = fontBase.Strikethrough
                .Superscript = fontBase.Superscript
                .Subscript = fontBase.<SPAN style="color:#00007F">Sub</SPAN>script
                .OutlineFont = fontBase.OutlineFont
                .Shadow = fontBase.Shadow
                .Underline = fontBase.Underline
                .ColorIndex = fontBase.ColorIndex
            <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">With</SPAN>
        <SPAN style="color:#00007F">Next</SPAN> intLtr
EndOfLoop:
    <SPAN style="color:#00007F">Next</SPAN> rngCell

    rngBaseCell.Select

<SPAN style="color:#00007F">End</SPAN> Sub</FONT>

HTH
 
Upvote 0

Forum statistics

Threads
1,214,636
Messages
6,120,666
Members
448,977
Latest member
moonlight6

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