Linking veritical transposed cells from a horizontal sheet

barryn

New Member
Joined
Sep 25, 2006
Messages
3
Hi, I am using 2 worksheets tabs. I have the data entered monthly for 30 items and each for 7 years, and listed horizontally on the 1st sheet. I wanted to link the cells on the second sheet by item & month to the first sheet; however, I need to have them listed vertically while still remaining linked to their corresponding monthly cell. I have tried copy paste special link, and have tried to transpose, but it didn't work? Is this possible? Any suggestions would be greatly appreciated.
 

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
this macro works if you assign it to a custom macro button on your toolbar. To use it, first copy the cells you want linked, then go to the other worksheet and click the button you assigned this macro to. It will then ask you to select the cell where you want the linked cells transposed to.

Code:
Sub TransposeLinks()
Dim SourceRange As Range
Dim TargetCell As Range
Dim i As Integer

    On Error Resume Next
    ActiveSheet.Paste Link:=True
    On Error GoTo 0
    
    Set SourceRange = Selection
    'Change all references to absolute
    SourceRange.Formula = Application.ConvertFormula(SourceRange.Formula, xlA1, xlA1, 1)

    On Error Resume Next
    Set TargetCell = Application.InputBox("Select Target Cell", "Tranpose Links", , , , , , 8)
    If Err <> 0 Then Exit Sub
    For i = 1 To SourceRange.Cells.Count
        TargetCell.Offset(0, i - 1).Formula = SourceRange.Cells(i, 1).Formula
    Next i
'
    If Intersect(SourceRange, Range(TargetCell, TargetCell.Offset(SourceRange.Cells.Count - 1))) Is Nothing Then SourceRange.Clear

End Sub
 
Upvote 0
Transpose

Is there an easier way to use =transpose on the second worksheet, and copy and paste it across the 30+ items?
 
Upvote 0
Try this: select the cells in the first worksheet and go to Insert -> Name -> Define. Give the range a name (no spaces allowed), for example name it MyRange. Then in the other worksheet, select the range you want to transpose it to (the number of columns should equal the number of rows in the original range). Then type in =Transpose(MyRange) and then press Ctrl +Shift + Enter.
 
Upvote 0
Worked-- But

Thanks that worked except for 1 thing. On worksheet 1, there were certain months with NO DATA, and when you transpose, it put a ZERO value into the months that had NO DATA. The problem with this is, the new chart on Worksheet 2 is for statiscal analysis, and some of the formulas are picking up the new values of ZERO and altering the results because they are counting the ZERO's as an input. Any suggestions on how to not pick up the ZERO value for worksheet two, from the NO DATA information cells in Worksheet 1?

Thanks in advance,
 
Upvote 0
The only way I can figure out to remove zeros is to put a space character into the empty cells in worksheet 1.
 
Upvote 0

Forum statistics

Threads
1,214,394
Messages
6,119,263
Members
448,881
Latest member
Faxgirl

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