Simple VBA help to download data from URL

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.
Okay, so here is the code. I'm uploading the file because of the userform, as I have named the controls for which the code works. It seemed to work for me in testing, but please try it out and let us know what you think. I believe it is what you asked for in your specs though.

Userform named "ufGetData" with the following code:
Code:
Option Explicit

Private Sub ckbOneDay_Click()
    Me.lblEnd.Enabled = Not Me.ckbOneDay.Value
    Me.cbMonthEnd.Enabled = Not Me.ckbOneDay.Value
    Me.cbDayEnd.Enabled = Not Me.ckbOneDay.Value
    Me.cbYearEnd.Enabled = Not Me.ckbOneDay.Value
    If Me.ckbOneDay.Value = False Then
        Me.cbDayEnd.Value = Me.cbDayStart.Value
        Me.cbMonthEnd.Value = Me.cbMonthStart.Value
        Me.cbYearEnd.Value = Me.cbYearStart.Value
    End If
End Sub

Private Sub UserForm_Initialize()
    Me.cbMonthStart.Clear
    Me.cbMonthEnd.Clear
    Me.cbDayStart.Clear
    Me.cbDayEnd.Clear
    Me.cbYearStart.Clear
    Me.cbYearEnd.Clear
    For i = 1 To 12
        Me.cbMonthStart.AddItem MonthName(i, False)
        Me.cbMonthEnd.AddItem MonthName(i, False)
    Next i
    For i = 1 To 31
        Me.cbDayStart.AddItem i
        Me.cbDayEnd.AddItem i
    Next i
    For i = Year(VBA.Date()) - 4 To Year(VBA.Date())
        Me.cbYearStart.AddItem i
        Me.cbYearEnd.AddItem i
    Next i
    Me.cbMonthStart.ListIndex = Month(VBA.Date()) - 1
    Me.cbDayStart.ListIndex = Day(VBA.Date()) - 1
    Me.cbYearStart.ListIndex = 4
    Me.ckbOneDay.Value = True
End Sub

Private Sub cmbCancel_Click()
    Unload Me
End Sub

Private Sub cmbGO_Click()

'Declare variables
    Dim dtStart As Date, dtEnd As Date, dtLoop As Date

    'Check for a valid start date
    If Len(Me.cbDayStart.Value) = 0 Or Len(Me.cbMonthStart.Value) = 0 Or Len(Me.cbYearStart.Value) = 0 Then
        MsgBox "Please select a start date!", vbCritical, "INCOMPLETE"
        Exit Sub
    End If

    'Check if a second date is used
    If Me.ckbOneDay.Value = False Then

    'If second date used, check for valid date
        If Len(Me.cbDayEnd.Value) = 0 Or Len(Me.cbMonthEnd.Value) = 0 Or Len(Me.cbYearEnd.Value) = 0 Then
            MsgBox "Please select an end date!", vbCritical, "INCOMPLETE"
            Exit Sub
        End If
    End If

    'Set start date variable
    dtStart = DateValue(Me.cbMonthStart.Value & " " & Me.cbDayStart.Value & ", " & Me.cbYearStart.Value)

    'Check if a second date is used
    If Me.ckbOneDay.Value = False Then

    'Set end date to start date if not used
        dtEnd = DateValue(Me.cbMonthEnd.Value & " " & Me.cbDayEnd.Value & ", " & Me.cbYearEnd.Value)

    'Check if end date is prior to start date (error trapping)
        If dtEnd < dtStart Then
            MsgBox "Your end date must be after your start date!", vbCritical, "ERROR!"
            Exit Sub
        End If
    Else

    'If no end date used, set as start date
        dtEnd = dtStart
    End If

    'Turn off some application settings to speed up code
    Call TOGGLEEVENTS(False)
    sErr = vbNullString

    'Loop through each day between dates, call routine individually
    For dtLoop = dtStart To dtEnd
        Call UnzipFile(dtLoop)
    Next dtLoop

    'Turn back on some application settings
    Call TOGGLEEVENTS(True)

    'Check out error message status from running the downloads, return a message depending on it's value
    If Len(sErr) > 0 Then
        MsgBox "There was a problem downloading the following files:" & DNL & sErr & NL & "Downloads successful.", vbExclamation, "DONE WITH ERRORS"
    Else
        MsgBox "All downloads completed successfully.", vbOKOnly, "DONE!"
    End If

    'Close the userform
    Unload Me

End Sub
Standard module named "modGetData" with the following code:
Code:
Option Explicit

Private Declare Function URLDownloadToFile Lib "urlmon" Alias "URLDownloadToFileA" (ByVal pCaller As Long, _
                                                                                    ByVal szURL As String, _
                                                                                    ByVal szFileName As String, _
                                                                                    ByVal dwReserved As Long, _
                                                                                    ByVal lpfnCB As Long) As Long

Public WB                           As Workbook
Public WS                           As Worksheet
Public i                            As Long
Public sErr                         As String

Public Const NL                     As String = vbNewLine
Public Const DNL                    As String = vbNewLine & vbNewLine

Sub LaunchUserform()
    Load ufGetData
    ufGetData.Show
End Sub

Sub UnzipFile(dtLook As Date)

'Set CLEANUP to True to delete zip file after extraction
'Leave as False to not delete zip file after extraction
    Const CLEANUP                   As Boolean = True

    'Variable declaration
    Dim oApp                        As Object
    Dim vFile                       As Variant
    Dim sFileName                   As Variant
    Dim aName                       As Variant
    Dim vFolderName                 As Variant
    Dim vSaveFileName               As Variant
    Dim sDay                        As String
    Dim sMonth                      As String
    Dim sYear                       As String
    Dim sDate                       As String
    Dim sExtractFileName            As String
    Dim ret                         As Long
    Dim iMonth                      As Long
    Dim aURLs(1 To 5, 1 To 4)       As Variant

    'Set file name variables
    sDay = CStr(Format(Day(dtLook), "00"))
    sMonth = UCase(CStr(MonthName(Month(dtLook), True)))
    iMonth = CStr(Format(Month(dtLook), "00"))
    sYear = CStr(Year(dtLook))
    sDate = Format(Day(dtLook), "00") & sMonth & sYear

    'EXAMPLES:
    'http://www.nseindia.com/content/historical/EQUITIES/2010/SEP/cm20SEP2010bhav.csv.zip
    'http://www.nseindia.com/content/historical/DERIVATIVES/2009/SEP/fo18SEP2009bhav.csv.zip
    'http://www.bseindia.com/bhavcopy/eq180909_csv.zip
    'http://www.bseindia.com/BSEDATA/gross/2009/SCBSEALL1809.zip
    'http://www.nseindia.com/archives/equities/mto/MTO_18092009.DAT

    'Loop through all 5 websites
    For i = 1 To 5
        Select Case i
        Case 1
            sFileName = "http://www.nseindia.com/content/historical/EQUITIES/" & sYear & "/" & sMonth & "/cm" & sDate & "bhav.csv.zip"
        Case 2
            sFileName = "http://www.nseindia.com/content/historical/DERIVATIVES/" & sYear & "/" & sMonth & "/fo" & sDate & "bhav.csv.zip"
        Case 3
            sFileName = "http://www.bseindia.com/bhavcopy/eq" & sDay & iMonth & sYear & "_csv.zip"
        Case 4
            sFileName = "http://www.bseindia.com/BSEDATA/gross/" & sYear & "/SCBSEALL" & sDay & iMonth & ".csv.zip"
        Case 5
            sFileName = "http://www.nseindia.com/archives/equities/mto/MTO_" & sDay & iMonth & sYear & ".DAT"
        End Select
    'sFilename
        aURLs(i, 1) = sFileName
    'aNames
        aURLs(i, 2) = Split(sFileName, "/")
    'vFolderName
        aURLs(i, 3) = CreateObject("WScript.Shell").SpecialFolders("Desktop") & "\"
    'vSaveFileName
        aURLs(i, 4) = aURLs(i, 3) & aURLs(i, 2)(UBound(Split(sFileName, "/")))

    'Check if the file exists locally in this location first
        If Len(Dir(CStr(aURLs(i, 4)), vbNormal)) = 0 Then
    'Download the file first to the Desktop
            ret = URLDownloadToFile(0, aURLs(i, 1), aURLs(i, 4), 0, 0)
    'See if the download happened correctly
            If ret = 0 Then
    'all went well
            Else
    'Something went wrong, grab the URL and pass for error messaging
    '            sErr = sErr & Format(dtLook, "mmm d, yyyy") & NL
                sErr = sErr & aURLs(i, 1) & NL
                Exit Sub
            End If
        Else
            If MsgBox("The file is already downloaded.  Continue anyway?", vbYesNo, "CONTINUE?") <> vbYes Then Exit Sub
        End If

    'Check if it is a zip file, if so, extract it
        If UCase(Right(aURLs(i, 4), 4)) = ".ZIP" Then

    'Set extraction name (same of file, less the ".zip" at the end)
            sExtractFileName = Split(aURLs(i, 4), "\")(UBound(Split(aURLs(i, 4), "\")))
            sExtractFileName = Left(sExtractFileName, Len(sExtractFileName) - 4)

    'Do the actual extraction
            Set oApp = CreateObject("Shell.Application")
            For Each vFile In oApp.Namespace(aURLs(i, 4)).items
                If Len(Dir(CStr(vFile), vbNormal)) <> 0 Then
                    If MsgBox(CStr(vFile) & " already exists.  Delete and replace?", vbYesNo, "REPLACE?") = vbYes Then
                        Kill aURLs(i, 3) & CStr(vFile)
                        oApp.Namespace(aURLs(i, 3)).CopyHere oApp.Namespace(aURLs(i, 4)).items.Item(CStr(vFile))
                    End If
                Else
                    oApp.Namespace(aURLs(i, 3)).CopyHere oApp.Namespace(aURLs(i, 4)).items.Item(CStr(vFile))
                End If
    '        oApp.Namespace(vFolderName).CopyHere oApp.Namespace(vSaveFileName).items.Item(CStr(vFile))
            Next vFile

    'Clean up zip files
            If CLEANUP Then
                Kill aURLs(i, 4)
            End If

        End If

    Next i

End Sub

Public Sub TOGGLEEVENTS(blnState As Boolean)
'Originally written by Zack Barresse
    With Application
        If Not blnState And Not ActiveWorkbook Is Nothing Then .Calculation = xlCalculationManual
        .DisplayAlerts = blnState
        .EnableEvents = blnState
        .ScreenUpdating = blnState
        If blnState Then .CutCopyMode = False
        If blnState Then .StatusBar = False
        If blnState And Not ActiveWorkbook Is Nothing Then .Calculation = xlCalculationAutomatic
    End With
End Sub
A standard button on the worksheet can call the following routine "LaunchUserform", set your dates in the userform, click the GO button. Test file attached in zip format.

HTH

Sir,

I thank you very much for spending your valuable time to help me. After testing the downloaded file i faced the following problems.

1. Didn't understand where the files are being downloaded. I suspect that they are being doanloaded to desktop. But i could see only .DAT file. Can you please modify the code to download the files to a folder named Macros/Input in E Drive?

2. I am using Excel 2010 if it could be of some help.

3. Excel sheet is not responding when i tested to download the data for more than one day.

Please let me know what changes do i need to make if any to resolve the above.

Thanks for providing a solution and it is what exactly i am looking for.

Regards,
Zaska
 
Upvote 0
This was built/tested in Excel 2010, since that is what you specified.

The destination was the desktop, yes. If you want to change the destination, look for this line in the code...
Code:
aURLs(i, 3) = CreateObject("WScript.Shell").SpecialFolders("Desktop") & "\"
...and change it to wherever you want, i.e. ...
Code:
aURLs(i, 3) = "E:\Macros\Input\"
Not sure about the hanging. Perhaps you can step through the code using F8? Hard to tell what is hanging on your machine since it runs for me.

@Valko: I clicked the Manage Attachments button. Is that a moderator thing only? Too many boards to remember so many rules..
 
Upvote 0
Quote:
Originally Posted by Zack Barresse View Post

@Valko: I clicked the Manage Attachments button. Is that a moderator thing

I think it was - years back. No more. As far as I know you quite literally might be the only one with that button, Zack. :)
 
Upvote 0
This was built/tested in Excel 2010, since that is what you specified.

The destination was the desktop, yes. If you want to change the destination, look for this line in the code...
Rich (BB code):
aURLs(i, 3) = CreateObject("WScript.Shell").SpecialFolders("Desktop") & "\"
...and change it to wherever you want, i.e. ...
Rich (BB code):
aURLs(i, 3) = "E:\Macros\Input\"
Not sure about the hanging. Perhaps you can step through the code using F8? Hard to tell what is hanging on your machine since it runs for me.

@Valko: I clicked the Manage Attachments button. Is that a moderator thing only? Too many boards to remember so many rules..

Sir,

I made the following changes in the code and finally it's working. I kindly request you to add few lines in the code to extract the downloaded .zip files in destination folder to .csv format.

Code:

Code:
Option Explicit

Private Declare Function URLDownloadToFile Lib "urlmon" Alias "URLDownloadToFileA" (ByVal pCaller As Long, _
                                                                                    ByVal szURL As String, _
                                                                                    ByVal szFileName As String, _
                                                                                    ByVal dwReserved As Long, _
                                                                                    ByVal lpfnCB As Long) As Long

Public WB                           As Workbook
Public WS                           As Worksheet
Public i                            As Long
Public sErr                         As String

Public Const NL                     As String = vbNewLine
Public Const DNL                    As String = vbNewLine & vbNewLine

Sub LaunchUserform()
    Load ufGetData
    ufGetData.Show
End Sub

Sub UnzipFile(dtLook As Date)

'Set CLEANUP to True to delete zip file after extraction
'Leave as False to not delete zip file after extraction
    Const CLEANUP                   As Boolean = [COLOR=Red]FALSE[/COLOR]

    'Variable declaration
    Dim oApp                        As Object
    Dim vFile                       As Variant
    Dim sFileName                   As Variant
    Dim aName                       As Variant
    Dim vFolderName                 As Variant
    Dim vSaveFileName               As Variant
    Dim sDay                        As String
    Dim sMonth                      As String
    Dim sYear                       As String
    Dim sDate                       As String
    Dim sExtractFileName            As String
    Dim ret                         As Long
    Dim iMonth                      As Long
    Dim aURLs(1 To 5, 1 To 4)       As Variant

    'Set file name variables
    sDay = CStr(Format(Day(dtLook), "00"))
    sMonth = UCase(CStr(MonthName(Month(dtLook), True)))
    iMonth = CStr(Format(Month(dtLook), "00"))
    sYear = CStr(Year(dtLook))
    sDate = Format(Day(dtLook), "00") & sMonth & sYear

    'EXAMPLES:
    'http://www.nseindia.com/content/historical/EQUITIES/2010/SEP/cm20SEP2010bhav.csv.zip
    'http://www.nseindia.com/content/historical/DERIVATIVES/2009/SEP/fo18SEP2009bhav.csv.zip
    'http://www.bseindia.com/bhavcopy/eq180909_csv.zip
    'http://www.bseindia.com/BSEDATA/gross/2009/SCBSEALL1809.zip
    'http://www.nseindia.com/archives/equities/mto/MTO_18092009.DAT

    'Loop through all 5 websites
    For i = 1 To 5
        Select Case i
        Case 1
            sFileName = "http://www.nseindia.com/content/historical/EQUITIES/" & sYear & "/" & sMonth & "/cm" & sDate & "bhav.csv.zip"
        Case 2
            sFileName = "http://www.nseindia.com/content/historical/DERIVATIVES/" & sYear & "/" & sMonth & "/fo" & sDate & "bhav.csv.zip"
        Case 3
            sFileName = "http://www.bseindia.com/bhavcopy/eq" & sDay & iMonth & sYear & "_csv.zip"
        Case 4
           [COLOR=Red] sFileName = "http://www.bseindia.com/BSEDATA/gross/" & sYear & "/SCBSEALL" & sDay & iMonth & ".zip"[/COLOR]
        Case 5
            sFileName = "http://www.nseindia.com/archives/equities/mto/MTO_" & sDay & iMonth & sYear & ".DAT"
        End Select
    'sFilename
        aURLs(i, 1) = sFileName
    'aNames
        aURLs(i, 2) = Split(sFileName, "/")
    'vFolderName
        [COLOR=Red]aURLs(i, 3) = "E:\Macros\Input\"[/COLOR]
    'vSaveFileName
        aURLs(i, 4) = aURLs(i, 3) & aURLs(i, 2)(UBound(Split(sFileName, "/")))

    'Check if the file exists locally in this location first
        If Len(Dir(CStr(aURLs(i, 4)), vbNormal)) = 0 Then
    'Download the file first to the Desktop
            ret = URLDownloadToFile(0, aURLs(i, 1), aURLs(i, 4), 0, 0)
    'See if the download happened correctly
            If ret = 0 Then
    'all went well
            Else
    'Something went wrong, grab the URL and pass for error messaging
    '            sErr = sErr & Format(dtLook, "mmm d, yyyy") & NL
                sErr = sErr & aURLs(i, 1) & NL
                Exit Sub
            End If
        Else
            If MsgBox("The file is already downloaded.  Continue anyway?", vbYesNo, "CONTINUE?") <> vbYes Then Exit Sub
        End If

    'Check if it is a zip file, if so, extract it
        If UCase(Right(aURLs(i, 4), 4)) = ".ZIP" Then

    'Set extraction name (same of file, less the ".zip" at the end)
            sExtractFileName = Split(aURLs(i, 4), "\")(UBound(Split(aURLs(i, 4), "\")))
            sExtractFileName = Left(sExtractFileName, Len(sExtractFileName) - 4)

    'Do the actual extraction
            Set oApp = CreateObject("Shell.Application")
            For Each vFile In oApp.Namespace(aURLs(i, 4)).items
                If Len(Dir(CStr(vFile), vbNormal)) <> 0 Then
                    If MsgBox(CStr(vFile) & " already exists.  Delete and replace?", vbYesNo, "REPLACE?") = vbYes Then
                        Kill aURLs(i, 3) & CStr(vFile)
                        oApp.Namespace(aURLs(i, 3)).CopyHere oApp.Namespace(aURLs(i, 4)).items.Item(CStr(vFile))
                    End If
                Else
                    oApp.Namespace(aURLs(i, 3)).CopyHere oApp.Namespace(aURLs(i, 4)).items.Item(CStr(vFile))
                End If
    '        oApp.Namespace(vFolderName).CopyHere oApp.Namespace(vSaveFileName).items.Item(CStr(vFile))
            Next vFile

    'Clean up zip files
            If CLEANUP Then
                Kill aURLs(i, 4)
            End If

        End If

    Next i

End Sub

Public Sub TOGGLEEVENTS(blnState As Boolean)
'Originally written by Zack Barresse
    With Application
        If Not blnState And Not ActiveWorkbook Is Nothing Then .Calculation = xlCalculationManual
        .DisplayAlerts = blnState
        .EnableEvents = blnState
        .ScreenUpdating = blnState
        If blnState Then .CutCopyMode = False
        If blnState Then .StatusBar = False
        If blnState And Not ActiveWorkbook Is Nothing Then .Calculation = xlCalculationAutomatic
    End With
End Sub


Thank you for such a valuable code.
 
Last edited:
Upvote 0
Sir,

I have faced the following problem in the code provided.

Code:
 sFileName = "http://www.bseindia.com/bhavcopy/eq" & sDay & iMonth & sYear & "_csv.zip"

In the above URL year format is different

Example : www.bseindia.com/bhavcopy/eq231211_csv.zip

Instead the code is taking as 2011

i have tried using iYear = CStr(Format(Year(dtLook), "00")) but it didn't work for me.

Regards,

Zaska
 
Upvote 0
iYear isn't a declared variable, sYear is. I know it may be confusing how I used iMonth as a string, but I needed two variables. I should've named it sMonth2 perhaps. You can change it if you want. I should have.

Try this line of code instead...
Code:
sFileName = "http://www.bseindia.com/bhavcopy/eq" & Format(dtLook, "ddmmyy") & "_csv.zip"
 
Upvote 0
Sir,

Thank you for the help , i have declared iYear as Long even then it didn't work for me. However i followed the code you have given above and it worked perfectly.

I could see that your code has few lines to extract the .zip files that are downloaded to E:\Macros\Input folder. However i don't understand why this isn't working.

The VBA code is downloading Four .zip files but they are not being extracted and .zip files are not being deleted after extracting.

Could you please tell me where i am going wrong ?

Since the destination folder has changed from desktop to E drive , do i need to modify any other lines in the code?

Regards,
Zaska
 
Upvote 0
Can you step through your code? Better yet, if it is only failing on the unzip portion, put a break point on this line...
Code:
If UCase(Right(aURLs(i, 4), 4)) = ".ZIP" Then
To do that easily, put your cursor on that line and hit F9. Then when you run your code it will break on that line when it comes to execute it, then you can step through each line using F8 to see what gets executed. Hover your mouse over any variable during break mode to see it's value, or better yet look in the Locals window (show it from the View menu).

It runs fine for me, so I'm not sure where it's going wrong.
 
Upvote 0

Forum statistics

Threads
1,225,135
Messages
6,183,065
Members
453,147
Latest member
Lacey D

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