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.
 

Some videos you may like

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand

btadams

Well-known Member
Joined
Jan 6, 2003
Messages
1,936
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
 

barryn

New Member
Joined
Sep 25, 2006
Messages
3
Transpose

Is there an easier way to use =transpose on the second worksheet, and copy and paste it across the 30+ items?
 

btadams

Well-known Member
Joined
Jan 6, 2003
Messages
1,936
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.
 

barryn

New Member
Joined
Sep 25, 2006
Messages
3
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,
 

btadams

Well-known Member
Joined
Jan 6, 2003
Messages
1,936
The only way I can figure out to remove zeros is to put a space character into the empty cells in worksheet 1.
 

Watch MrExcel Video

Forum statistics

Threads
1,109,424
Messages
5,528,685
Members
409,830
Latest member
KT50

This Week's Hot Topics

  • Change military grades into rank
    Afternoon all Need help with formula that will change military rank (i.e. 1, 2, 3 into Amn, A1C, SrA). Running IF formula that does not work...
  • VBA COUNTIF SOLUTION
    Hi The following are the errors spread across the several columns from E to Q ie. 13 columns across several sheets with more than 500 rows per...
  • INSERT ROW WITH SPECIFIS TEXT IN A COLUMN
    Hi All! How can identify that that the row to be inserted has to be inserted before 1st row with specific text in column F. If I record the...
  • Auto-Create a monthly Sign in sheet for preschool students
    The image below is what each page looks like. Above is space for the "Child Name" "Month" "Class" School days are obviously Monday-Friday but...
  • VBA vlookup multiple results
    Hi folks, Hopefully someone out there can help. I have a list to vlookup which works (ish). the lookup only picks up the first instance of the...
  • Extract values for earliest/latest times
    I am trying to put together a formula to get the earliest start time, the latest end time from column A for each person in Column B-F without the...
Top