這篇我們抓取大盤指數與期貨指數,並計算兩者中間價差,有興趣的可以參考以下程式碼。
Option Explicit Const xlStartYear As Integer = 2014 Const xlStartMonth As Integer = 1 Const xlStartDay As Integer = 1 Const xlFilePath As String = "C:\期貨下載資料\" Sub 大盤與期貨() Application.ScreenUpdating = False ClaerChartObjects With Workbooks(1).Worksheets(1) .UsedRange.ClearContents .Cells(1, 1) = "交易日期" .Cells(1, 2) = "大盤指數" .Cells(1, 3) = "期貨指數" .Cells(1, 4) = "指數價差" End With 大盤指數 期貨指數 指數價差 Worksheets(1).Cells.EntireColumn.AutoFit Worksheets(1).Cells.HorizontalAlignment = xlCenter 繪圖 Application.ScreenUpdating = True End Sub Sub 大盤指數() Dim url As String Dim i, j, k, xlCount, xlDay, xlDaysOfMonth As Integer xlDay = xlStartDay xlCount = 2 For i = xlStartYear To Year(Date) For j = xlStartMonth To Month(Date) xlDaysOfMonth = Day(DateSerial(Format(i, "0000"), Format(j, "00") + 1, 1) - 1) For k = xlDay To xlDaysOfMonth url = "http://www.twse.com.tw/ch/trading/exchange/MI_INDEX/MI_INDEX_print.php?genpage=genpage/Report" & Format(i, "0000") & Format(j, "00") & "/A112" & Format(i, "0000") & Format(j, "00") & Format(k, "00") & "MS.php&type=csv" With Workbooks.Open(url) .ActiveSheet.Range("B3:B3").Select If ActiveCell.Value <> Empty Then .ActiveSheet.Range("B3:B3").Copy _ Destination:=Workbooks(1).Worksheets(1).Range("B" & xlCount & ":B" & xlCount) Workbooks(1).Worksheets(1).Cells(xlCount, 1) = Format(i, "0000") & "/" & Format(j, "00") & "/" & Format(k, "00") xlCount = xlCount + 1 End If .Close 0 End With Next k If k >= xlDaysOfMonth Then xlDay = 1 End If Next j Next i End Sub Sub 期貨指數() Dim i, j, k, xlDays, xlCount, xlRow, xlPos As Integer Dim xlDate, url As String Dim xlFilename As String xlCount = 2 For i = xlStartYear To Year(Date) For j = xlStartMonth To Month(Date) xlDays = Day(DateSerial(Format(i, "0000"), Format(j, "00") + 1, 1) - 1) url = "http://www.taifex.com.tw/chinese/3/3_1_2dl.asp?datestart=" & Format(i, "0000") & "%2F" & Format(j, "00") & "%2F" & Format(1, "00") & "&dateend=" & Format(i, "0000") & "%2F" & Format(j, "00") & "%2F" & Format(xlDays, "00") & "&COMMODITY_ID=TX" xlFilename = xlFilePath + "\期貨指數" + Format(i, "0000") + Format(j, "00") + ".CSV" 下載檔案 url, xlFilename With Workbooks.Open(xlFilename) xlRow = Range(.ActiveSheet.Range("A:A").Find("價差商品").Address).Row - 3 For k = 1 To xlDays xlDate = Format(i, "0000") & "/" & Format(j, "0") & "/" & Format(k, "0") If Not .ActiveSheet.Range("A1:A" & xlRow).Find(CDate(xlDate)) Is Nothing Then xlPos = Range(.ActiveSheet.Range("A1:A" & xlRow).Find(CDate(xlDate)).Address).Row .ActiveSheet.Range("G" & xlPos).Copy _ Destination:=ThisWorkbook.Worksheets(1).Range("C" & xlCount) xlCount = xlCount + 1 End If Next k .Close 0 End With Next j Next i End Sub Sub 下載檔案(url As String, xlFilename As String) Dim oXMLHTTP, objStream As Object Set oXMLHTTP = CreateObject("Microsoft.XMLHTTP") Set objStream = CreateObject("ADODB.stream") With oXMLHTTP .Open "POST", url, False .send If .readyState = 4 Then '.Status = 200 With objStream .Type = 1 .Open .Write oXMLHTTP.ResponseBody If Dir(xlFilename) <> "" Then Kill xlFilename .SaveToFile xlFilename .Close End With End If End With Set oXMLHTTP = Nothing Set objStream = Nothing End Sub Sub 指數價差() Dim i, nRow As Integer nRow = Worksheets(1).Range("A65536").End(xlUp).Row For i = 2 To nRow Range("D" & i) = Range("B" & i) - Range("C" & i) Next i End Sub Sub 繪圖() Dim i, nRow As Integer ClaerChartObjects nRow = Worksheets(1).Range("A65536").End(xlUp).Row With ActiveSheet.ChartObjects.Add(Left:=268, Top:=33, Width:=701, Height:=445).Chart .HasTitle = True .ChartTitle.Text = "大盤與期貨指數" With .SeriesCollection.NewSeries .ChartType = xlLineMarkers '圖表類型 .Values = Range("B2:B" & nRow) '數值 .XValues = Range("A2:A" & nRow) 'X軸 .Name = "大盤指數" '圖表名稱 .AxisGroup = xlPrimary End With With .SeriesCollection.NewSeries .ChartType = xlLineMarkers '圖表類型 .Values = Range("C2:C" & nRow) '數值 .XValues = Range("A2:A" & nRow) 'X軸 .Name = "期貨指數" '圖表名稱 .AxisGroup = xlPrimary End With With .SeriesCollection.NewSeries .ChartType = xlLineMarkers '圖表類型 .Values = Range("D2:D" & nRow) '數值 .XValues = Range("A2:A" & nRow) 'X軸 .Name = "指數價差" '圖表名稱 .AxisGroup = xlSecondary End With '.Legend.Delete .Legend.Position = xlBottom 'xlLegendPositionBottom 或 xlBottom都可 With .Axes(xlCategory) 'X軸設定 .HasTitle = True .AxisTitle.Text = Range("A1:A1") .AxisTitle.Font.Size = 12 End With With .Axes(xlValue, xlPrimary) '左邊 Y軸設定 .HasTitle = True .AxisTitle.Text = Range("B1:B1") .AxisTitle.Font.Size = 12 .AxisTitle.Orientation = xlVertical '字體方向旋轉 .AxisTitle.VerticalAlignment = xlCenter .AxisTitle.HorizontalAlignment = xlCenter End With With .Axes(xlValue, xlSecondary) '右邊 Y軸設定 .HasTitle = True .AxisTitle.Text = Range("C1:C1") .AxisTitle.Font.Size = 12 .AxisTitle.Orientation = xlVertical '字體方向旋轉 .AxisTitle.VerticalAlignment = xlCenter .AxisTitle.HorizontalAlignment = xlCenter End With End With 'Color Index : http://msdn.microsoft.com/en-us/library/cc296089(office.12).aspx End Sub Sub ClaerChartObjects() Dim Chtobj As ChartObject For Each Chtobj In ActiveSheet.ChartObjects Chtobj.Delete Next End Sub
執行畫面