Access Memo Field copy with VBA to Excel truncates at 255 characters (1 Viewer)

Rx_

Nothing In Moderation
Local time
Today, 02:28
Joined
Oct 22, 2009
Messages
2,803
Two Solutions to address moving an Access Memo field into Excel when string has > 255 characters. What is the best of the 2 solutions?

All my 'reports' use Excel VBA (Access Reports are not used). The Excel reports can have 40,000 records. Speed to create the report can be an issue.

Question: Describing 2 Solutions below to address moving Access memo fields with > 255 characters into Excel, what would be the best methodology to use? (or is there another solution?)

After running this code
Code:
720         ObjXL.DisplayAlerts = False      
                ObjXL.Columns("X:X").Select
                ObjXL.Selection.NumberFormat = "@" ' set column to Text
730         ObjXL.Worksheets(intWorksheetNum).Cells(intRowPos, 1).CopyFromRecordset rsNutsAndBolts
The Comments column are limited to 255 characters. So, the CopyFromRecordset (recordsetvariable) creates the 255 character limitation.

The reason? The 255 character limit is because CopyFromRecordset sutomatically uses the Characters property of the Range object. The 255 limit would not be there if the Cell Value property is used to assign the string to that cell.
Dim sRx as String ' String Prescription
sRx = "String with > 255 characters ... you fill in the rest ...."
Cells(1, 1).Value = sRx ' Cell's Value property assignment can be very large
------------------------------------------------
Solution 1:
The record set is still in memory. By using a loop, a cursor can start with record 1 (memo column) and assign that value to the Excel row / column using the .value as shown above. Basically, this moves one memo field at a time, record by record. e.g. Read First recordset in Access, copy to variable, assign value to Excel row/column Then move next on each Access and Excel.

Solution 2: An Access Memo filed [RxNotes] can have up to 750 characters. Cut it apart into three new fields that end up out in the very right Excel columns AA, AB, AC.
Note1=Mid([RxNotes],1,250)
Note2=Mid([RxNotes],251,250)
Note3=Mid([RxNotes],501,250)
Then using Excel Object - Concat the cells back cell by cell...
X2=CONCATENATE(AA2,AB2,AC2))
Then delete the columns AA, AB, AC to hide the evidence
-------------------------------------------------------
Neither solution is all that elequent. So if anyone has a better solution, please be sure to speak up.

B.T.W. Read about this and by golly, it made a difference
ConcatComments = "'" & CommentString
Before using the CopyFromRecordset be sure to add a single quote in front of the large string.
Why? Ok, since you asked...
Turns out the interface between Access and Excel look for this to prepare Excel immediately for the string to be a string, not something else.
Some of my strings had weird print characters that kind of looked like Japenese characters. It seemed random, it always happened if the string was 255 or more characters (ramdonly, not always). The single quote doesn't show up in Excel, but got rid of all the noise.
 

boblarson

Smeghead
Local time
Today, 01:28
Joined
Jan 12, 2001
Messages
32,059
I have found that in some instances I have to export using VBA and do it record by record instead of CopyFromRecordset.
 

Rx_

Nothing In Moderation
Local time
Today, 02:28
Joined
Oct 22, 2009
Messages
2,803
Thanks Bob, Happy Holidays. That is a great point.
Probably the best answer.
I did that on another report. The maintence was a somewhat higher as the customer ended up throwing me dozens of changes. However, as you indicate, it really did exactly what it was designed. Total control over everything.

Maybe I will try the one-column approach after bringing in the bulk of the data with the one-liner.
 

Rx_

Nothing In Moderation
Local time
Today, 02:28
Joined
Oct 22, 2009
Messages
2,803
SOLVED:
The Main table Primary Key (e.g. Customer_ID) links to a Comment table where the Customer_ID is a FK (Foreign Key) The Comment table has a Date, User Name, and Comment field. The Comment field is of type Memo.
Each PK can have zero to many Comments.
The Access Query calls a custom function that takes the PK then Concat (paste together) each comment e.g. All_Comments: ConcatComments([Customers].[ID_Customer])
The problem was: Setting the recordset to a query, the All_Comments frequently had over 255 Characters.
Then the CopyFromRecordset to Excel - the query would truncate the Comments (of type Memo) to 255 max.

To Solve:
Made a local Table out of the query (make table query). Then deleted the data.
KEY: Change local table Comments field to type MEMO.

Used Append query to repopulate the Local table from the query.

400 'Set rsNutsAndBolts = CurrentDb.OpenRecordset(strNutsBolts, dbOpenSnapshot, dbReadOnly) ' direct query truncated Comment to 255 characters
410 Set rsNutsAndBolts = CurrentDb.OpenRecordset("tbl_NutsAndBolts", dbOpenTable, dbSeeChanges) ' use local table tbl_NutsAndBolts '
' The local table has the Comment field set to type MEMO
' this was the same query - the append destination is the local table
760 ObjXL.Worksheets(intWorksheetNum).Cells(intRowPos, 1).CopyFromRecordset rsNutsAndBolts
Note: since Record set is now opening a local table, with the field of type Memo - it no longer truncates the fiels to 255 characters when sending data to Excel.

Recap:
Create local table, change Remarks field to type Memo.
Before running query, delete all records in local table, use Append Query to repopulate local table (with Comment field of type Memo),
Use Copy from Recordset to copy the local table over to Excel
Run delete query to clear out local table (save disk space on local table).

Some Excel fields have 3,000 characters now. The limitation of 255 characters is gone.

QUESTION: Is there a way in an Access Query to desginate the output data type? This would probably eliminate the need to create a local table.
There isn't a CMemo (like the CInt).
Saw a post that discussed convert to XML - XML oftern has characters over 255 in lenghth. Don't know how that might be used...
 

Rx_

Nothing In Moderation
Local time
Today, 02:28
Joined
Oct 22, 2009
Messages
2,803
' This is just some of the general steps used to populate the temp table that has a comment field set to Memo type. Then move the data into Excel. The Comments field in Excel has many multiples of 255 characters.

DoCmd.SetWarnings False
DoCmd.RunSQL "DELETE * FROM tbl_NutsAndBolts" ' delete all records in local Table
300 strNutsBolts = "INSERT INTO Rpt_NutsAndBolts (field names here...) "
330 strNutsBolts = strNutsBolts & " SELECT (SqLstatement here) "
350 strNutsBolts = strNutsBolts & " FROM (sql statement) "
360 strNutsBolts = strNutsBolts & " WHERE (sql statement with parmaters) "
370 strNutsBolts = strNutsBolts & " ORDER BY (sql statement); "

DoCmd.SetWarnings False
DoCmd.RunSQL strNutsBolts ' repopulate all records in local CommentReport Table that has Comment as type Memo
' Create a new object instance of Excel
590 Set ObjXL = New Excel.Application
600 ObjXL.EnableEvents = False
640 ObjXL.Visible = False 650 ObjXL.Workbooks.Add
730 ObjXL.Columns("X:X").Select
740 ObjXL.Selection.NumberFormat = "@" ' set as TEXT for memo
750 ObjXL.Selection.ColumnWidth = 60
Set rsNutsAndBolts = CurrentDb.OpenRecordset("Rpt_NutsAndBolts", dbOpenTable, dbSeeChanges) ' the local table with Comments in Memo type field

765 ObjXL.Worksheets(intWorksheetNum).Cells(intRowPos, 1).CopyFromRecordset rsNutsAndBolts ' Copy table based Recordset to Excel
780 intMaxRecordCount = rsNutsAndBolts.RecordCount - 1 ' - use for max rows returned in formatting later
'Debug.Print "max record count is " & intMaxRecordCount
' ------- Create Header in new Excel based on Query
790 intMaxheaderColCount = rsNutsAndBolts.Fields.count - 1
800 For intHeaderColCount = 0 To intMaxheaderColCount
810 If Left(rsNutsAndBolts.Fields(intMaxheaderColCount).Name, 3) <> "xxx" Then ' Future use - adding xxx in cross tab queries for fields to exclude
820 ObjXL.Worksheets(intWorksheetNum).Cells(intRowPos - 1, intHeaderColCount + 1) = rsNutsAndBolts.Fields(intHeaderColCount).Name ' Relative to intRowPos
830 End If
840 Next intHeaderColCount
' Get the number of records and columns returned for Excel to use.
 

Rx_

Nothing In Moderation
Local time
Today, 02:28
Joined
Oct 22, 2009
Messages
2,803
Just a quick followup - other interesting solutions evaluated:
http://support.microsoft.com/kb/208801 Interesting information - not totally complete
http://www.accessmvp.com/kdsnell/EXCEL_Import.htm example Very bottom of page
http://www.mrexcel.com/forum/excel-...mit-visual-basic-applications-workaround.html for VBA users - Excel Range property differences that relate to 255 characters
Looked at over 50 sites - these above are worth looking at.
This is just an FYI for anyone who is searching for a custom solution.
 

Users who are viewing this thread

Top Bottom