473,385 Members | 1,942 Online
Bytes | Software Development & Data Engineering Community
Post Job

Home Posts Topics Members FAQ

Join Bytes to post your question to a community of 473,385 software developers and data experts.

Export to excel faster

Hello!

I currently have a button that exports a query, customized by the user on the form, to excel. The data that is exported is compared to older values (from a history table) and depending on the changes, the cellcolor is changed, so I need to format each cell individually. I have it working, but with many columns and more than 2500 records it can take like 15 minutes to export. Here's what I do:
Expand|Select|Wrap|Line Numbers
  1. 'fill in data in excel cells
  2. intI = 2
  3. Do While Not rsCurLL.EOF()
  4.     intCellCnt = 1
  5.     For Each fd In rsCurLL.Fields
  6.     'get the IDLine of the current record
  7.     If intCurIDLine <> rsCurLL.Fields("IDLine").Value Then
  8.         intCurIDLine = rsCurLL.Fields("IDLine").Value
  9.         'move the rsOldLL pointer to the matching record
  10.         rsOldLL.FindFirst ("[IDLine] = " & intCurIDLine & "")
  11.         If rsOldLL.NoMatch Then
  12.         blnIDLineNotFound = True
  13.         Else
  14.         blnIDLineNotFound = False
  15.         End If
  16.     End If
  17.     'if the "Deleted" field is not in teh view query it will not be exported
  18.     If fd.Name = "Deleted" Then
  19.         If varDeleted > 0 Then
  20.         xlSheet.Cells(intI, intCellCnt).Value = rsCurLL.Fields(fd.Name).Value
  21.         xlSheet.Cells(intI, intCellCnt).HorizontalAlignment = xlLeft
  22.         xlSheet.Cells(intI, intCellCnt).BorderAround xlContinuous
  23.         'if the current line is not present in the linelist_issued table, the line is new, so empty the old value
  24.         If blnIDLineNotFound = False Then
  25.             strFValueOld = Nz(rsOldLL.Fields(fd.Name).Value)
  26.         Else
  27.             strFValueOld = ""
  28.         End If
  29.         strFValueNew = Nz(rsCurLL.Fields(fd.Name).Value)
  30.         If strFValueNew <> strFValueOld Then
  31.             xlSheet.Cells(intI, intCellCnt).Interior.Color = RGB(192, 192, 192)
  32.         End If
  33.         If rsCurLL.Fields("Deleted").Value = True Then
  34.             xlSheet.Cells(intI, intCellCnt).Interior.Color = RGB(153, 204, 255)
  35.         End If
  36.         intCellCnt = intCellCnt + 1
  37.         End If
  38.     'if the "IDLine" field is not in the view query it will not be exported
  39.     ElseIf fd.Name = "IDLine" Then
  40.         If varIDLine > 0 Then
  41.         xlSheet.Cells(intI, intCellCnt).Value = rsCurLL.Fields(fd.Name).Value
  42.         xlSheet.Cells(intI, intCellCnt).HorizontalAlignment = xlLeft
  43.         xlSheet.Cells(intI, intCellCnt).BorderAround xlContinuous
  44.         If blnIDLineNotFound = False Then
  45.             strFValueOld = Nz(rsOldLL.Fields(fd.Name).Value)
  46.         Else
  47.             strFValueOld = ""
  48.         End If
  49.         strFValueNew = Nz(rsCurLL.Fields(fd.Name).Value)
  50.         If strFValueNew <> strFValueOld Then
  51.             xlSheet.Cells(intI, intCellCnt).Interior.Color = RGB(192, 192, 192)
  52.         End If
  53.         If rsCurLL.Fields("Deleted").Value = True Then
  54.             xlSheet.Cells(intI, intCellCnt).Interior.Color = RGB(153, 204, 255)
  55.         End If
  56.         intCellCnt = intCellCnt + 1
  57.         End If
  58.     ElseIf fd.Name = "revision" Then
  59.         'do nothing
  60.     Else
  61.         xlSheet.Cells(intI, intCellCnt).Value = rsCurLL.Fields(fd.Name).Value
  62.         xlSheet.Cells(intI, intCellCnt).HorizontalAlignment = xlLeft
  63.         xlSheet.Cells(intI, intCellCnt).BorderAround xlContinuous
  64.         If blnIDLineNotFound = False Then
  65.         strFValueOld = Nz(rsOldLL.Fields(fd.Name).Value)
  66.         Else
  67.         strFValueOld = ""
  68.         End If
  69.         strFValueNew = Nz(rsCurLL.Fields(fd.Name).Value)
  70.         If strFValueNew <> strFValueOld Then
  71.         xlSheet.Cells(intI, intCellCnt).Interior.Color = RGB(192, 192, 192)
  72.         End If
  73.         If rsCurLL.Fields("Deleted").Value = True Then
  74.         xlSheet.Cells(intI, intCellCnt).Interior.Color = RGB(153, 204, 255)
  75.         End If
  76.         intCellCnt = intCellCnt + 1
  77.     End If
  78.     Next
  79.     'display the current record
  80.     intCurRecord = intCurRecord + 1
  81.     lblCountCur.Caption = intCurRecord
  82.     Forms("MainMenuNew").Repaint
  83.     'move to next record
  84.     rsCurLL.MoveNext
  85.     intI = intI + 1
  86. Loop
Is there a faster/more efficient way to do this? Any other tips are welcome since this is the first time I'm trying something like this.

Thanks!
Jul 31 '08 #1
5 8934
Stewart Ross
2,545 Expert Mod 2GB
Hi. The fastest way to export data to Excel will not work in your case, because you have so much cell formatting to do. Looking at your code I doubt there is much more you can do to it to speed it up unless you lose the formatting, as it is the formatting itself which is slowing things down.

The fastest way to transfer data to Excel is to use a variant array to store the data, an array whose dimensions are reset to match the current number of rows and columns you need to transfer. Instead of accessing Excel directly, loop processing transfers data to the array, and then as a final step the array is assigned to Excel in one operation. This is much faster (around 10 times as fast) than using the Cells method to write data to Excel cell-by-cell.

How I resolve it in cases such as yours is to open a pre-formatted Excel worksheet - a template sheet, although not an XLT file as such - and copy the data to the pre-formatted cells using the array method. I size the template to the maximum which the data will ever need, then delete any unused rows/columns within the processing of the worksheet after transferring the data from the array.

This hybrid method works well for me, and may be something you wish to consider at a later date.

-Stewart

Code extract from one transfer routine, with use of dynamic array picked out
Expand|Select|Wrap|Line Numbers
  1. Dim RowData() As Variant '<< DYNAMIC ARRAY
  2. Dim RowRef As Long, ColRef As Long
  3. Dim CellRange As Excel.Range
  4. ' ...
  5. FirstPass = True
  6. RowCounter = 0
  7. Set RS = CurrentDb.OpenRecordset(ProgQueryName)
  8. Do Until RS.EOF
  9.     ...
  10.     If PrevDept <> DeptRef Then
  11.     If Not FirstPass Then
  12.     ...
  13.     End If
  14.     FirstPass = False
  15.     ReDim RowData(MaxProgs, MaxCols) << SET UP ACTUAL DIMENSIONS
  16.         ...
  17.     End If
  18.     RowData(RowCounter, 0) = CourseName ' << WRITE DATA TO THE ARRAY
  19.     RowData(RowCounter, 1) = Block
  20.     RowData(RowCounter, 2) = FEHE
  21.     RowData(RowCounter, 4 + SessionOffset) = Enr
  22.     ...
  23.     PrevDept = DeptRef
  24.     RS.MoveNext
  25. Loop
  26. RS.Close
  27. If Not FirstPass Then
  28.     With xlRep.CurrentWorkSheet
  29.     Set CellRange = .Range(.Cells(StartRow, 2), .Cells(StartRow + RowCounter - 1, MaxCols + 1)) '<< SET UP THE CELL RANGE FOR THE ARRAY TRANSFER
  30.     End With
  31.     CellRange.Value = RowData '<< TRANSFER DATA FROM ARRAY TO EXCEL
  32.     xlRep.DeleteRows RowCounter + StartRow, LastRow
  33.     ...
  34. End If
Aug 3 '08 #2
Hi. The fastest way to export data to Excel will not work in your case, because you have so much cell formatting to do. Looking at your code I doubt there is much more you can do to it to speed it up unless you lose the formatting, as it is the formatting itself which is slowing things down.

The fastest way to transfer data to Excel is to use a variant array to store the data, an array whose dimensions are reset to match the current number of rows and columns you need to transfer. Instead of accessing Excel directly, loop processing transfers data to the array, and then as a final step the array is assigned to Excel in one operation. This is much faster (around 10 times as fast) than using the Cells method to write data to Excel cell-by-cell.

How I resolve it in cases such as yours is to open a pre-formatted Excel worksheet - a template sheet, although not an XLT file as such - and copy the data to the pre-formatted cells using the array method. I size the template to the maximum which the data will ever need, then delete any unused rows/columns within the processing of the worksheet after transferring the data from the array.

This hybrid method works well for me, and may be something you wish to consider at a later date.

-Stewart
Thanks a lot for your reply Stewart. Too bad I can't use your method in my case, since I would lose the formatting. It is good to know there is such a fast way to export data to excel though. I should be able to use it in the future, thanks!
Aug 5 '08 #3
NeoPa
32,556 Expert Mod 16PB
Would a Copy/Paste not do the trick pretty efficiently?

I'm planning that shortly in a current project.
Aug 5 '08 #4
Stewart Ross
2,545 Expert Mod 2GB
Hi NeoPa. Copy/Paste does work - but it is tabular in format (so no ability to define where the data goes if you need a particular cell layout that is not just rectangular), is actually slower than other methods (the copy to the clipboard has to be complete before the data can be pasted at all), and the default paste overwrites any formatting. Although Paste Text can be used to resolve the formatting problem, it in turn can cause problems with fields formatted in certain ways (numerics formatted with leading zeros for example).

In copying recordsets to Excel the Excel copy from recordset method is far faster than copy-paste. The use of a dynamic variant array is similarly fast, particularly for data that is not strictly tabular throughout.

What really slows Excel automation down is any form of range or worksheet selection prior to copying a value, and using bespoke formatting a cell at a time. To take an instance, to form a border round a single cell means making at least four automation calls between Access and Excel with all the communication overheads that are entailed along with it. Range formatting is more efficient, because the range can be formatted in more or less the same number of communication calls as a single cell.

-Stewart
Aug 5 '08 #5
NeoPa
32,556 Expert Mod 16PB
Thanks for all that Stewart.

I always try to do my formatting by range where possible, and I have recently come across some of the problems associated with transferring data between cells in Excel. I tend to use the .Value = .Value approach where possible, but that tends to require formatting beforehand and afterwards.

I will see what I can come up with in my project - then I may get back to you for some further clarification on any outstanding matters. Obviously in another thread, as I don't want to hijack this one any further than I have already :D
Aug 5 '08 #6

Sign in to post your reply or Sign up for a free account.

Similar topics

1
by: Matt | last post by:
I have an ASP page that calls ASP routines that I created that execute a database query and return the results to a recordset. I then iterate through the recordset and display the data in a table....
5
by: Maria L. | last post by:
Hi, I need to export the content of a DataGrid (in Windows application in C#), into an Excel spreadsheet. Anyone knows how to do this? Any code snippets would help! thanks a lot, Maria
4
by: Tomek | last post by:
Hi, How could I export data from table or query to excel file in VB.NET? Thanks in advance, Tomek
2
by: Agnes | last post by:
I can export the data to an excel(quit slow , for 5k records, It need 20mins) Now, my problem is how can I join another table from another database ? "select I.invno,I.company,C.telno,C.faxno from...
4
by: Jiro Hidaka | last post by:
Hello, I would like to know of a fast way to export data source data into an Excel sheet. I found a way from C# Corner(Query Tool to Excel using C# and .NET) which is a neat little way of...
13
by: Hemant Sipahimalani | last post by:
The following piece of code is being used to export HTML to excel. HttpContext.Current.Response.ContentType = "application/vnd.ms-excel"...
5
by: Simon | last post by:
Dear reader, With the export command you can export a query to Excel. By activate this command a form pop's up with the following text:
1
by: smaczylo | last post by:
Hello, I've recently been asked to work with Microsoft Access, and while I feel quite comfortable with Excel, I'm at a complete loss with databases. If someone could help me with this issue I'm...
2
hemantbasva
by: hemantbasva | last post by:
Note We need to have a template on server for generating report in multiple sheet as we do not had msoffice on server moreover this require a batch job to delete excel file created by the...
0
by: ryjfgjl | last post by:
If we have dozens or hundreds of excel to import into the database, if we use the excel import function provided by database editors such as navicat, it will be extremely tedious and time-consuming...
0
by: ryjfgjl | last post by:
In our work, we often receive Excel tables with data in the same format. If we want to analyze these data, it can be difficult to analyze them because the data is spread across multiple Excel files...
0
by: emmanuelkatto | last post by:
Hi All, I am Emmanuel katto from Uganda. I want to ask what challenges you've faced while migrating a website to cloud. Please let me know. Thanks! Emmanuel
0
BarryA
by: BarryA | last post by:
What are the essential steps and strategies outlined in the Data Structures and Algorithms (DSA) roadmap for aspiring data scientists? How can individuals effectively utilize this roadmap to progress...
1
by: Sonnysonu | last post by:
This is the data of csv file 1 2 3 1 2 3 1 2 3 1 2 3 2 3 2 3 3 the lengths should be different i have to store the data by column-wise with in the specific length. suppose the i have to...
0
marktang
by: marktang | last post by:
ONU (Optical Network Unit) is one of the key components for providing high-speed Internet services. Its primary function is to act as an endpoint device located at the user's premises. However,...
0
by: Hystou | last post by:
Most computers default to English, but sometimes we require a different language, especially when relocating. Forgot to request a specific language before your computer shipped? No problem! You can...
0
Oralloy
by: Oralloy | last post by:
Hello folks, I am unable to find appropriate documentation on the type promotion of bit-fields when using the generalised comparison operator "<=>". The problem is that using the GNU compilers,...
0
jinu1996
by: jinu1996 | last post by:
In today's digital age, having a compelling online presence is paramount for businesses aiming to thrive in a competitive landscape. At the heart of this digital strategy lies an intricately woven...

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.