Wrox Programmer Forums
| Search | Today's Posts | Mark Forums Read
Access Discussion of Microsoft Access database design and programming. See also the forums for Access ASP and Access VBA.
Welcome to the p2p.wrox.com Forums.

You are currently viewing the Access section of the Wrox Programmer to Programmer discussions. This is a community of software programmers and website developers including Wrox book authors and readers. New member registration was closed in 2019. New posts were shut off and the site was archived into this static format as of October 1, 2020. If you require technical support for a Wrox book please contact http://hub.wiley.com
  #1 (permalink)  
Old November 14th, 2008, 03:46 PM
Registered User
 
Join Date: Nov 2008
Location: Columbus, OH, USA.
Posts: 4
Thanks: 0
Thanked 0 Times in 0 Posts
Default OutputTo .csv

I'm working on (what should be) a simple application to output CSVs to upload to a pay-roll system.

The problem I'm running into is that the header rows must have specific names to be accepted by the pay-roll system. Naturally, a # symbol appears in one of the header rows. When I try to export using the built-in export function and a transfer-text macro Access replaces the # symbol with a ..

I've tried to use the outputto, but it only gives me the option of outputting to a txt, and that's formatted with |s so it's not very helpful.

Any thoughts?

Nick
  #2 (permalink)  
Old November 17th, 2008, 09:04 AM
Friend of Wrox
Points: 9,611, Level: 42
Points: 9,611, Level: 42 Points: 9,611, Level: 42 Points: 9,611, Level: 42
Activity: 0%
Activity: 0% Activity: 0% Activity: 0%
 
Join Date: Mar 2004
Location: Washington, DC, USA.
Posts: 3,069
Thanks: 0
Thanked 10 Times in 10 Posts
Default

Have you looked up all the available TransferText options in Help? I think if you indicate that it is acExportDelim in the TransferType clause, this should remove the pipes. Is that how it is being formatted now?

DoCmd.TransferText(TransferType, SpecificationName, TableName, FileName, HasFieldNames, HTMLTableName, CodePage)

You may also want to set the HasFieldNames clause to True, to get the column names out intact. That might resolve the # issue.

In the alternative, you could manually export the csv file yourself, using a Scripting.FileSystem, GetFile, FileExists, CreateFile, WriteLine etc. Do you know how to do that?

Did any of that help?

mmcdonal

Look it up at: http://wrox.books24x7.com
  #3 (permalink)  
Old November 17th, 2008, 10:18 AM
Registered User
 
Join Date: Nov 2008
Location: Columbus, OH, USA.
Posts: 4
Thanks: 0
Thanked 0 Times in 0 Posts
Default

I can get TransferText to output to a csv with my headers. The problem with TrasnferText is that it replaces the "#" with a "."

OutputTo leaves the "#" intact, but there is no .csv option with OutputTo. That's where I get the pipes.

I have no idea how to export using the method you've described below. Any further help would be appreciated.



Nick
  #4 (permalink)  
Old November 17th, 2008, 10:50 AM
Friend of Wrox
Points: 9,611, Level: 42
Points: 9,611, Level: 42 Points: 9,611, Level: 42 Points: 9,611, Level: 42
Activity: 0%
Activity: 0% Activity: 0% Activity: 0%
 
Join Date: Mar 2004
Location: Washington, DC, USA.
Posts: 3,069
Thanks: 0
Thanked 10 Times in 10 Posts
Default

I see the problem. I would do the scripting solution. If you are sending out the results from a query, for example, you could do this, based on the NorthWind database and assuming that you are overwriting any earlier files with the same name:

'======Code Starts=======
Dim fso As Variant
Dim objFile As Variant
Dim sFile As String
Dim sLine As String
Dim rs As ADODB.Recordset
Dim sSQL As String

sFile = "C:\Documents And Settings\All Users\Desktop\MySampleFile.csv"

Set fso = CreateObject("Scripting.FileSystemObject")
Set objFile = fso.CreateTextFile(sFile)
'Write first line with Column Names

sLine = "Product ID" & ", " & "Product Name"
objFile.WriteLine(sLine)

sSQL = "SELECT * FROM Current Product List"
Set rs = New ADODB.Recordset
rs.Open sSQL, CurrentProject.Connection, adOpenDynamic, adLockOptimistic

Do Until rs.EOF

   sLine = rs("Product ID") & ", " & rs("Product Name")
   objFile.WriteLine(sFile)

rs.MoveNext
Loop

objFile.Close

'=======Code Ends=======

This will allow you to control all the characters in the strings that are being written.

This would work, but I do ADO exclusively, and Northwind doesn't, but you should get the idea.

Did that help?

mmcdonal

Look it up at: http://wrox.books24x7.com
  #5 (permalink)  
Old November 17th, 2008, 10:51 AM
Friend of Wrox
Points: 9,611, Level: 42
Points: 9,611, Level: 42 Points: 9,611, Level: 42 Points: 9,611, Level: 42
Activity: 0%
Activity: 0% Activity: 0% Activity: 0%
 
Join Date: Mar 2004
Location: Washington, DC, USA.
Posts: 3,069
Thanks: 0
Thanked 10 Times in 10 Posts
Default

Sorry, that should be:

Do Until rs.EOF

   sLine = rs("Product ID") & ", " & rs("Product Name")
   objFile.WriteLine(sLine)

rs.MoveNext
Loop

NOT:

Do Until rs.EOF

   sLine = rs("Product ID") & ", " & rs("Product Name")
   objFile.WriteLine(sFile)

rs.MoveNext
Loop


mmcdonal

Look it up at: http://wrox.books24x7.com
  #6 (permalink)  
Old November 17th, 2008, 01:14 PM
Registered User
 
Join Date: Nov 2008
Location: Columbus, OH, USA.
Posts: 4
Thanks: 0
Thanked 0 Times in 0 Posts
Default

Yep, that worked with a few minor tweaks. I am going to need to change the file name every time (because, of course, the pay-roll system requires a unique file name for every upload), but I'm relatively confident I can figure that part out. Thanks for your help.

Below is the the tweaked code.

======Code Starts=======
Dim fso As Variant
Dim objFile As Variant
Dim sFile As String
Dim sLine As String
Dim db As Database
Dim rs As Recordset

sFile = "C:\Documents And Settings\All Users\Desktop\MySampleFile.csv"

Set fso = CreateObject("Scripting.FileSystemObject")
Set objFile = fso.CreateTextFile(sFile)
'Write first line with Column Names

sLine = "CO CODE" & "," & "Batch ID" & "," & "File #" & "," & "Reg Earnings"
objFile.WriteLine (sLine)

Set db = CurrentDb
Set rs = db.OpenRecordset("select * from qryMRDDTestExport")



Do Until rs.EOF

   sLine = rs("CO CODE") & "," & rs("Batch ID") & "," & rs("File #") & "," & rs("Reg Earnings")
   objFile.WriteLine (sLine)

rs.MoveNext
Loop


objFile.Close
=======Code Ends=======

Nick
  #7 (permalink)  
Old November 17th, 2008, 01:28 PM
Friend of Wrox
Points: 9,611, Level: 42
Points: 9,611, Level: 42 Points: 9,611, Level: 42 Points: 9,611, Level: 42
Activity: 0%
Activity: 0% Activity: 0% Activity: 0%
 
Join Date: Mar 2004
Location: Washington, DC, USA.
Posts: 3,069
Thanks: 0
Thanked 10 Times in 10 Posts
Default

Normally I would do this for file names:

Dim iMonth As Integer
Dim iYear As Integer
Dim iDay As Integer

iMonth = DatePart("m", Date())
iYear = DatePart("yyyy", Date())
iDay = DatePart("d", Date())

sFile = "C:\Documents And Settings\All Users\Desktop\MySampleFile_" & _
iYear & "_" & iMonth & "_" & iDay & ".csv"

So today I would get

MySampleFile_2008_11_17.csv

Or, you could put the date first, so you can sort them in your folder in the order they were run.

Glad that worked for you.


mmcdonal

Look it up at: http://wrox.books24x7.com
  #8 (permalink)  
Old November 17th, 2008, 01:37 PM
Registered User
 
Join Date: Nov 2008
Location: Columbus, OH, USA.
Posts: 4
Thanks: 0
Thanked 0 Times in 0 Posts
Default

Thanks you again.

Nick


Similar Threads
Thread Thread Starter Forum Replies Last Post
docmd.outputto Scripts82 Access VBA 0 March 9th, 2006 04:19 AM
Outputto exceeded limit of rows Renee Voice Access VBA 2 February 26th, 2006 04:47 PM
outputto command ajmil11 Access 1 February 1st, 2006 08:21 AM
OutputTo Macro Question Corey Access 1 September 19th, 2005 11:36 PM
Capture OutputTo Destination and Filename? afleming Access VBA 2 October 18th, 2004 08:59 AM





Powered by vBulletin®
Copyright ©2000 - 2020, Jelsoft Enterprises Ltd.
Copyright (c) 2020 John Wiley & Sons, Inc.