![]() |
|
#1
|
|||
|
|||
![]()
Got what I see as a complicated project. I do all the bookkeeping for a farmers market. I have a excel spreadsheet set up with all the vendors for the year. On any particular week that they are present I will enter that data into my spreadsheet. I would like to see about how to merge it into a word document for a weekly accounting form that I use. In the past I have been handwriting the accounting form, but if I can automate this it would be greatly helpful.
|
#2
|
|||
|
|||
![]() Quote:
|
#3
|
|||
|
|||
![]()
No it doesnt have to be in word, but what i see as the true challenge is that if that particular vendor was not there in a particular week, i dont want them to show up on the accounting form. I just want the vendors that were there that particular work
|
#4
|
|||
|
|||
![]() Quote:
and their amounts. Is this correct? if so it can be done a couple ways. The first way is with an auto filter applied and select "Non Blanks" on the date specified column then copy and paste those results on your new worksheet or even your word template. The other would be to do it with VBA. Once we confirm that the 7-24 example above is correct I can start on some VBA code for you to do this. |
#5
|
|||
|
|||
![]()
Yes that date is correct
I dont know a lot about VBA code, so i may need lots of help putting this together. But thank you for any help that you can provide me. Thank you, |
#6
|
|||
|
|||
![]() Quote:
Here is the code for the workbook Code:
Sub WedData() ' Macro recorded 9/15/2013 by JRErickson ' Dim WedDate As Date Dim WedColTot As Integer Dim CurCol As String Dim CurRange As String Range("'Print Out'!y1:z500").ClearContents Range("'Print Out'!b4").ClearContents Range("'Print Out'!d3").ClearContents Range("a1").Select WedDate = InputBox("Please enter Wednesday date in proper format.", "Enter Date") Cells.Find(What:=WedDate, After:=ActiveCell, LookIn:=xlFormulas, _ LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:=xlNext, _ MatchCase:=False, SearchFormat:=False).Activate ActiveCell.Offset(1, 0).Select CurCell = ActiveCell.Column y = 8 For X = 1 To 104 If ActiveCell.Value <> "" Then Range("'Print Out'!Z" & y) = ActiveCell.Value Range("'Print Out'!Y" & y) = Cells(y, 2) y = y + 1 ActiveCell.Offset(1, 0).Select Else ActiveCell.Offset(1, 0).Select End If Next X Range("'Print Out'!b4").Value = WedDate Range("'Print Out'!d3").Value = "Wednesday" Range("a3").Select End Sub Sub SatData() ' Macro recorded 9/15/2013 by JRErickson ' Dim SatDate As Date Dim SatColTot As Integer Dim CurCol As String Dim CurRange As String Range("'Print Out'!y1:z500").ClearContents Range("'Print Out'!b4").ClearContents Range("'Print Out'!d3").ClearContents Range("a1").Select SatDate = InputBox("Please enter Saturday date in proper format.", "Enter Date") Cells.Find(What:=SatDate, After:=ActiveCell, LookIn:=xlFormulas, _ LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:=xlNext, _ MatchCase:=False, SearchFormat:=False).Activate ActiveCell.Offset(1, 0).Select CurCell = ActiveCell.Column y = 8 For X = 1 To 179 If ActiveCell.Value <> "" Then Range("'Print Out'!Z" & y) = ActiveCell.Value Range("'Print Out'!Y" & y) = Cells(y, 2) y = y + 1 ActiveCell.Offset(1, 0).Select Else ActiveCell.Offset(1, 0).Select End If Next X Range("'Print Out'!b4").Value = SatDate Range("'Print Out'!d3").Value = "Saturday" Range("a3").Select End Sub This was fun. Let me know what you think or if you have any questions. Take care. |
#7
|
||||
|
||||
![]()
Ok, I see the problem. I was staring at it suspiciously for quite a while, but I couldn't figure out exactly what it did so I wasn't sure it was wrong. I had to run the thing interactively to pin it down; and that's how you're going to do it, too.
Go to the Excel VBA editor, put the cursor on the first line of the program (the one that says "Sub SatData()"), and hit <F9>. Notice how that line turns sort of burgandy; it means you've put a "break" or "breakpoint" on that line; that means when your program gets to that point in the execution, it'll stop and call for your attention. Now go back to the Saturdays worksheet and start the macro. Immediately you're back in the macro editor again, looking at that line—only now it's highlighted in yellow. That means the program is running, and it's about to run that statement. Now hit <F8> just once, and watch the yellow highlighting advance. It jumps over the Dim statements to the first ClearContents command. That's the statement it's about to execute in the VBA program. <F8> is a command to the editor to execute just one statement in your program, and then to pause again. Hit <F8> again and it'll jump to the next statement. If you pause at this point and go look at your "Print Out" worksheet, you'll notice that the contents of Y1:Z500 are indeed now cleared. Hit <F8> again, several times, one at a time—feel free to watch the results in the worksheet—until you get to the InputBox function. When you hit <F8> on that one, the input box will be displayed on your screen. Go ahead and enter the desired date—2013-06-22, it was, in this case. Now, back in the VBA editor, the Cells.Find statement is highlighted. Before you hit <F8> again, cause your mouse arrow to hover over a few items in your program: Put the cursor over SatDate—any instance of SatDate in your program, it doesn't matter which one. A little box will pop up showing the current value of SatDate (presumably "2013-06-22", just now). Have the cursor hover over the variable a few lines down that you named y; just now it'll say it's "Empty", because you haven't yet set it to anything. Hover over ActiveCell.Value a few lines further down yet; on my machine just now it says "Business Name", because the active cell is currently A1. Feel free to explore a little. When you're ready, hit <F8>; the program has now done the search for the date you typed in. If you go back to the worksheet, you'll see that that date is now selected in row 1. But when you go back to the VBA editor and hit <F8> again, the next statement is executed, which in your worksheet moves the selection down one row. We're almost to the problem. Go ahead and step down through "y = 8" (and now y isn't Empty any more), the For loop, the If statement, and so on until you get to "Range("'Print Out'!Y" & y) = Cells(y, 2)". Here we'll stop and discuss a moment. The variable y is the row number for the output on the Print Out worksheet. Your program has already set 'Print Out'!Z8 to the dollar value (you can go and check, if you like). Now the next statement is supposed to set 'Print Out'!Y8 to the name (in column B, ie 2) from the input row on the Saturdays sheet. But wait—that may be what you want it to do, but it isn't what you told it to do. You told it to use the value not from that row but from Cells(y,2). Hover your mouse over "Cells(y, 2)", and you'll see that it displays the wrong name, "Bishop, Derrick", not "Anders, Nelli" as it should. Why? Cells(y, 2) says to pull from row y, column 2; and since y = 8, you pulled it from the Saturdays worksheet, row 8, column 2. Right column, wrong row; y is the variable you're using for your output row. How to tell your program which input row to use? Well, I don't think much of using ActiveCell and moving it around; most people say that slows your program down unnecessarily. If we keep this up together, I'd just as soon show you some better ways. But for now, since you're already using ActiveCell, just to keep it simple you could do it this way: Code:
Range("'Print Out'!Z" & y) = ActiveCell.Value row = ActiveCell.Row Range("'Print Out'!Y" & y) = Cells(row, 2) Code:
Range("'Print Out'!Z" & y) = ActiveCell.Value Range("'Print Out'!Y" & y) = Cells(ActiveCell.Row, 2) ...But there are some other problems with this program that I'd like to talk about, aside from the obvious bug. These are not exactly wrong, but there are ways to make it easier to run: 1) Rather than have the user type in the desired date (and risk it being typed in wrong, or using the wrong format), it seems to me it's easier on the user to point to the correct column just by putting using the arrow keys to put the selection somewhere in that column. That also enables you to dump the concept of having two different programs; just use whichever worksheet the user points to. 2) Rather than telling your program which rows to look at (1 to 104 for Wed, 1 to 179 for Sat), have your program find the right ending row by itself. That way you don't have to keep adjusting it whenever you add enough new shops to the worksheets. There are a few other things but they're relatively minor and they'll probably come to you anyway, after a little more practice. But these two will be significant improvements in ease of use and of programming. |
#8
|
|||
|
|||
![]() Quote:
The FOR statement is definitely not the best it could be how would you go about doing a DO Until when a lot of the cells are already blank? Again thank you for the feedback. |
#9
|
||||
|
||||
![]() Quote:
Quote:
Quote:
As for the loop itself, I probably would do it pretty much the same way you did. Oh, I have a preference for changing the output row before the write instead of after, and I never name variables X any more (because of a mishap in another language entirely; but those are more programming style than The One Right Way to do something; any programmer will tell you there are lots and lots of ways to skin every cat you ever saw. |
#10
|
|||
|
|||
![]()
Okay I have one little request on this. I have been playing around with it all morning long, and I am unsure of how to accomplish this
In the report sheet, you set a total of 50 spaces. I could and have had more than 50 vendors in a given week. If you could adjust it so that there are between 70 and 80 spaces. We are a growing market and what I am trying to accomplish here is establishing better record keeping for the future. Thank you, Jonathan |
#11
|
||||
|
||||
![]()
Jonathan, I agree with your goal—to expand the size of the report to allow for growth, I mean. But rather than adjust it for you, I think we ought to fix it so you can understand for yourself how. Excelledsoftware may be softer-hearted, but I'm all about teaching the man to fish ... even at the risk of his going hungry a little, at first.
Let's see what he says. If he agrees with me, you'll have to do it, but one or both of us will explain how. I'd start by asking questions. For example: You say you played with it all morning. What, exactly did you try? It could be you were on the right track but just couldn't figure out how to make it work. |
#12
|
|||
|
|||
![]()
Bob
Thank you. Learning would be my prefered method of getting this done. The things that I tried to do were just first insert new rows into the sheet and then fill the formulas into this. The second thing I tried to do was to insert cells in those 4 rows and again fill the formulas into this None of this seemed to work, because I dont understand the relation between the vba code that has been written and the y & z columns that are in the reports sheet and how all of that pulls into the actual report. I took a visual basic class many years ago in college, but that was in 2000, and a lot has happened in the years to push all that information out of my head. Like I said about 8 years ago, I had the opportunity to work on a access database that someone else had put a ton of work into it and had a ton of underlying vba code, but this excel code seems vastly different to me, so I have a difficult time understanding it. Thank you, Jonathan English |
#13
|
||||
|
||||
![]()
I would love for you to understand the relation between the VBA code and what comes out on the Print out worksheet; and if you want, we can talk about that as a side question. If you've taken a VBA class before, then you should be able to get it all to come back. Let me know if you want to do that. But if I remember excelledsoftware's solution, you should be able to expand the worksheet without having to change the macro he wrote for you. All his program did was write out a list of contact persons and dollar figures in Y:Z starting at row 8. Getting it into a double-column listing is all the work of formulae in A8:D32. I believe you can expand on that without having to know anything more about the VBA program than that it writes its output to Y8:Zn, where n = "as far down as necessary".
Given that, take a look at the formulae in A8:D32. In particular, note that the formulae in A8:A32 identical to B8:B32, but that A8:B32 are different from C8:D32. How are they different? What (exactly) do they do? I think if you look at the difference, and figure out what the two different formulae mean, you'll have a broad hint about how to proceed from there. I'm not abandoning you; but start there, and if you don't get it yet, come back and ask more questions. |
#14
|
|||
|
|||
![]() Quote:
|
#15
|
||||
|
||||
![]()
Oh, I should have added this: The difference between the VBA stuff you did for Access and what you see here isn't a difference in the VBA language itself; it's in the "objects" that Access and Excel use. It makes sense, really; Access thinks in terms of records, forms and filters, while Excel has cells, rows, columns and worksheet functions. There are many overlapping concepts, but the properties and methods you use for one are different from the other because the applications themselves are different.
If you're not sure what I'm talking about—if you're not sure what properties and methods are—well, neither was I, only a few years ago, and it caused me lots of confusion when I tried to write Excel macros. Once I got it clear in my head, it was fine—better than fine, actually, because object-oriented programming, though different from plain Basic or PL/1 or REXX or what-have you, enables you to do some things much more easily. But knowing the VBA language is only half the battle; to use VBA on Excel you have to get to know the Excel "object model", and when you then have to use it on Access you have to learn the Access object model as a separate task. Knowing Excel doesn't enable you to use Access, and knowing VBA/Excel doesn't enable you to use VBA/Access either—or not fluently, at least. |
![]() |
|
![]() |
||||
Thread | Thread Starter | Forum | Replies | Last Post |
![]() |
ragesz | Word Tables | 1 | 09-29-2013 06:14 PM |
converting a word document to a data file for mail merge | drsuis | Mail Merge | 4 | 02-21-2013 03:34 PM |
![]() |
navysalad | Mail Merge | 6 | 01-07-2012 06:50 PM |
![]() |
daym | Publisher | 2 | 05-01-2011 03:45 AM |
How do I set up the fields in mail merge word 07 from my data base | mbcrabber | Mail Merge | 4 | 06-06-2010 01:25 PM |