Basically, I have data on multiple rows and columns. How do I plot a line chart with the data onto one single continuous line? Attachment of example data included. Need to graph the line from Jan 2000 to Oct 2012
Example123.xlsx
Basically, I have data on multiple rows and columns. How do I plot a line chart with the data onto one single continuous line? Attachment of example data included. Need to graph the line from Jan 2000 to Oct 2012
Example123.xlsx
Put the date 1/1/2000 in cell P5, then put this formula in P6:
Formula:
=DATE(YEAR(P5),MONTH(P5)+1,1)
Format both cells as mmm yy, then copy the formula from P6 down the column. Then put this formula in Q5:
Formula:
=INDEX($C$5:$N$17,MATCH(YEAR(P5),$B$5:$B$17,0),MATCH(TEXT(P5,"mmm"),$C$4:$N$4,0))
then copy this down.
Now that you have your data in two continuous columns, you can use this as the source for your graph.
Hope this helps.
Pete
Follow-up question: what if instead of months at the top, I have it in Q1, Q2, Q3 and Q4? I copied your formula for Q5, and move the colored boxes to the corresponding areas, but it came out with error.
Example1234.xlsx
You need different formulae to be able to transpose that table. For example, put this formula in cell H26:
Formula:
="Q"&MOD(ROWS($1:1)-1,4)+1&" 20"&TEXT(INT((ROWS($1:1)-1)/4),"00")
When this is copied down it will give you successive quarters for each year, i.e.:
Q1 2000
Q2 2000
Q3 2000
Q4 2000
Q1 2001
Q2 2001
and so on...
Then you could have this formula in I26:
Formula:
=INDEX($C$26:$F$38,MATCH(--RIGHT(H26,4),$B$26:$B$38,0),MATCH(LEFT(H26,2),$C$25:$F$25,0))
and copy this down.
I've put both sets of formulae in the attached file.
In answer to your earlier question about the INDEX formula, it has the syntax:
INDEX(table,row,column)
where table covers the cells that make up the data that you want to retrieve, and the row and column parameters (derived from MATCH functions) define which cell you want to return the data from. The first MATCH function is looking for the row, and so it is looking to see where the year in column P occurs in column B, and the second MATCH function is finding which column the month appears in row 4. The formula that I've just given you above follows a similar syntax, though the first MATCH is looking for the year from column H, and the second MATCH is looking for the Quarter and seeing where this appears in row 25. Note that the cells used for the two tables are different.
Hope this helps.
Pete
Wow, it worked! Thanks!
Do you mind explaining the mechanics behind how you condense the data into one column for Column Q?
There are currently 1 users browsing this thread. (0 members and 1 guests)
Bookmarks