An Efficient Way of Adding Values to A Worksheet Row By Row

Ark68

Well-known Member
Joined
Mar 23, 2004
Messages
4,616
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
Sorry for the vague title ... I am kinda at a loss of words on how to best describe what I am looking to do.

I am using Excel VBA to extract, analyse and format worksheet data to create a KML file. I have thousands of rows of data to be compiled into the final KML project.
The data is one worksheet, and the KML is built line by line in the destination worksheet.
The task is to put each new KML code on the row immediately below the previous.

It seems simple, but I am looking for efficient code to advancethe target row by one with each new line of KML.

The way I have been doing it is as simple as this ... (sample)

Code:
With ws_destination
    .range("A1") =  "/?xml version=" & Chr(34) & "1.0" & Chr(34) & " encoding=" & Chr(34) & "UTF-8" & Chr(34) & "?>"
    .range("A2") =  "/kml xmlns=" & Chr(34) & "http://www.opengis.net/kml/2.2" & Chr(34) & " xmlns:gx=" & Chr(34) & "http://www.google.com/kml/ext/2.2" & Chr(34) & " xmlns:kml=" & Chr(34) & "http://www.opengis.net/kml/2.2" & Chr(34) & " xmlns:atom=" & Chr(34) & "http://www.w3.org/2005/Atom" & Chr(34) & ">"    
    .range("A3") = "    /Document>"
     ...
End With

And so on. Each new line is referenced by a cell range value. Of course this works, but if I need to add a line anywhere tjrough the code, I have to change ALL the numbers in the cell reference manually. An annoying task when dealing with hundreds of lines of code.

Then I tried ... (sample)

Code:
x=1
With ws_destination
    .range("A" & x) =  "/?xml version=" & Chr(34) & "1.0" & Chr(34) & " encoding=" & Chr(34) & "UTF-8" & Chr(34) & "?>"
    x = x + 1    
    .range("A" & x) =  "/kml xmlns=" & Chr(34) & "http://www.opengis.net/kml/2.2" & Chr(34) & " xmlns:gx=" & Chr(34) & "http://www.google.com/kml/ext/2.2" & Chr(34) & " xmlns:kml=" & Chr(34) & "http://www.opengis.net/kml/2.2" & Chr(34) & " xmlns:atom=" & Chr(34) & "http://www.w3.org/2005/Atom" & Chr(34) & ">"    
    x = x + 1
    .range("A" & x) = "    /Document>"
    x = x + 1
     ...
End With

This to works, and resolves the need to have to manually change row references in cell ranges as was necessary in the first example. But with this method, I'm doubling the amount of lines of code, which not only makes for tedious coding, but may impact the performance of the script.

Can anyone suggest a more efficient method of doing what I need to accomplish?

I did try this, but the result is an "Automation error". Clearly this is not a doable method, but was worth the try I suppose.

Code:
With ws_dest
    ActiveWindow.DisplayGridlines = False
    .Columns("A").ColumnWidth = 255
    x = 0
    .Range("A" & x + 1) = "/?xml version=" & Chr(34) & "1.0" & Chr(34) & " encoding=" & Chr(34) & "UTF-8" & Chr(34) & "?/"
    .Range("A" & x + 1) = "/kml xmlns=" & Chr(34) & "http://www.opengis.net/kml/2.2" & Chr(34) & " xmlns:gx=" & Chr(34) & "http://www.google.com/kml/ext/2.2" & Chr(34) & " xmlns:kml=" & Chr(34) & "http://www.opengis.net/kml/2.2" & Chr(34) & " xmlns:atom=" & Chr(34) & "http://www.w3.org/2005/Atom" & Chr(34) & "/"
    .Range("A" & x + 1) = "    /Document/"
    ....
End With
 
Last edited:

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.
How about
Code:
With ws_destination
    .Range("A" & Rows.Count).End(xlUp).Offset(1) = "/?xml version=" & Chr(34) & "1.0" & Chr(34) & " encoding=" & Chr(34) & "UTF-8" & Chr(34) & "?>"
    .Range("A" & Rows.Count).End(xlUp).Offset(1) = "/kml xmlns=" & Chr(34) & "http://www.opengis.net/kml/2.2" & Chr(34) & " xmlns:gx=" & Chr(34) & "http://www.google.com/kml/ext/2.2" & Chr(34) & " xmlns:kml=" & Chr(34) & "http://www.opengis.net/kml/2.2" & Chr(34) & " xmlns:atom=" & Chr(34) & "http://www.w3.org/2005/Atom" & Chr(34) & ">"
    .Range("A" & Rows.Count).End(xlUp).Offset(1) = "    /Document>"
     ...
End With
 
Upvote 0
Hello Fluff.
Sorry for taking to so long to acknowledge your support. Your suggestion is exactly what I was needing, thank you!
 
Upvote 0
Glad to help & thanks for the feedback
 
Upvote 0
Why not use Resize with an array?
Code:
With ws_destination.Range("A" & Rows.Count).End(xlUp).Offset(1).Resize(3)
    .Value = Application.Transpose(Array("/?xml version=" & Chr(34) & "1.0" & Chr(34) & " encoding=" & Chr(34) & "UTF-8" & Chr(34) & "?/", _
                                                   "http://www.opengis.net/kml/2.2" & Chr(34) & " xmlns:gx=" & Chr(34) & "http://www.google.com/kml/ext/2.2" & Chr(34) & " xmlns:kml=" & Chr(34) & "http://www.opengis.net/kml/2.2" & Chr(34) & " xmlns:atom=" & Chr(34) & "http://www.w3.org/2005/Atom" & Chr(34) & "/", _
                                                   "    /Document/"))
End With
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,022
Latest member
Mohamed Magdi Tawfiq Emam

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top