最新消息

[公告2014/05/30] 如有需要將部落格中,任何一篇文章的程式碼使用在商業用途,請與我聯繫。

[公告2015/04/26] Line版的 iInfo程式與投資應用 群組已上線想加入的朋友們,請先查看 "入群須知" 再與我聯繫 Line : aminwhite5168,加入請告知身分與回答 "入群須知" 的問題。

[公告2018/04/22] 台北 Python + Excel VBA 金融資訊爬蟲課程,課程如網頁內容 金融資訊爬蟲班:台北班 Python 金融資訊爬蟲、EXCEL VBA 金融資訊爬蟲

[公告2019/01/08] 請注意:我再次重申,部落格文章的程式碼,是要提供各位參考與學習,一旦網頁改版請自行修改,別要求東要求西要我主動修改,你們用我寫東西賺錢了、交差了,請問有分我一杯羹嗎?既然賺錢沒分我,請問有什麼理由要求我修改,如果沒能力改,就花錢來找我上課。

[公告2019/12/01] 若各位有 Excel VBA 案子開發需求,歡迎與我聯繫,可接案處理。

[公告2020/05/22] 頁面載入速度慢,起因為部分JS來源(alexgorbatchev.com)失效導致頁面載入變慢,目前已做調整,請多見諒。

2014年4月9日 星期三

VBA抓選擇權與三大法人未平倉餘額

今天補上用VBA抓每日選擇權交易未平倉餘額的資料,一樣也將資料轉成視覺化圖形,未來再對該圖轉換成長條圖,有興趣的可以參考以下程式碼。
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
    
    If Dir(xlFilePath, vbDirectory) = "" Then
        MkDir (xlFilePath)
    End If

    ClaerChartObjects
    
    With Workbooks(1).Worksheets(1)
        .UsedRange.ClearContents
        .Cells(1, 1) = "交易日期"
        .Cells(1, 2) = "自營商買權"
        .Cells(1, 3) = "投信買權"
        .Cells(1, 4) = "外資及陸資買權"
        .Cells(1, 5) = "自營商賣權"
        .Cells(1, 6) = "投信賣權"
        .Cells(1, 7) = "外資及陸資賣權"
    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, xlPos, xlRow, xlDays, xlDayNo As Integer
    Dim xlDate, xlFilename As String
    
    xlCount = 2

    If Hour(Time) >= 0 And Hour(Time) < 14 Then
       xlDayNo = Day(Date) - 1
    Else
        xlDayNo = Day(Date)
    End If

    url = "http://www.taifex.com.tw/chinese/3/7_12_10dl.asp?syear=" & xlStartYear & "&smonth=" & xlStartMonth & "&sday=" & xlStartDay & "&eyear=" & Year(Date) & "&emonth=" & Month(Date) & "&eday=" & xlDayNo & "&COMMODITY_ID=TXO"
    
    'xlFilename = Application.ThisWorkbook.Path + "\" + "交易數.CSV"
    xlFilename = xlFilePath + "交易數.CSV"
    
    下載檔案 url, xlFilename
    
    With Workbooks.Open(xlFilename)
        xlRow = .ActiveSheet.Range("A65536").End(xlUp).Row
        For i = xlStartYear To Year(Date)
            For j = xlStartMonth To Month(Date)
                xlDays = Day(DateSerial(Format(i, "0000"), Format(j, "00") + 1, 1) - 1)
                For k = xlStartDay To xlDays
                    xlDate = Format(i, "0000") & "/" & Format(j, "0") & "/" & Format(k, "0")
                    
                    If Not .ActiveSheet.Range("A:A").Find(CDate(xlDate), , xlValues, xlWhole, xlByRows, xlNext, True) Is Nothing Then
                        xlPos = Range(.ActiveSheet.Range("A:A").Find(CDate(xlDate), , xlValues, xlWhole, xlByRows, xlNext, True).Address).Row
                        ThisWorkbook.Worksheets(1).Range("A" & xlCount) = CDate(xlDate)
                        
                        .ActiveSheet.Range("O" & xlPos & ":O" & (xlPos + 2)).Copy
                        ThisWorkbook.Worksheets(1).Range("B" & xlCount).PasteSpecial Paste:=xlPasteValues, Transpose:=True
                        
                        .ActiveSheet.Range("O" & (xlPos + 3) & ":O" & (xlPos + 5)).Copy
                        ThisWorkbook.Worksheets(1).Range("E" & xlCount).PasteSpecial Paste:=xlPasteValues, Transpose:=True
                        
                        xlCount = xlCount + 1
                    End If
                Next k
            Next j
        Next i
        .Close 0
    End With
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
    
    ClaerChartObjects
    
    nRow = Worksheets(1).Range("A65536").End(xlUp).Row
    With ActiveSheet.ChartObjects.Add(Left:=558, Top:=33, Width:=701, Height:=445).Chart
    
        .HasTitle = True
        .ChartTitle.Text = "選擇權未平倉餘額"
        
        With .SeriesCollection.NewSeries
            .ChartType = xlLineMarkers      '圖表類型
            .Values = Range("D2:D" & nRow)  '數值
            .XValues = Range("A2:A" & nRow) 'X軸
            .Name = "外資及陸資買權"        '圖表名稱
            .AxisGroup = xlPrimary
        End With
        
        With .SeriesCollection.NewSeries
            .ChartType = xlLineMarkers      '圖表類型
            .Values = Range("G2:G" & nRow)  '數值
            .XValues = Range("A2:A" & nRow) 'X軸
            .Name = "外資及陸資賣權"        '圖表名稱
            .AxisGroup = xlPrimary
        End With
        
        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("E2:E" & nRow)  '數值
            .XValues = Range("A2:A" & nRow) 'X軸
            .Name = "自營商賣權"            '圖表名稱
            .AxisGroup = xlPrimary
        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 = "外資及陸資"          '左邊 Y軸名稱
        '    .AxisTitle.Font.Size = 12
        '    .AxisTitle.Orientation = xlVertical     '字體方向旋轉
        '    .AxisTitle.VerticalAlignment = xlCenter
        '    .AxisTitle.HorizontalAlignment = xlCenter
        'End With
                
        'With .Axes(xlValue, xlSecondary)            '右邊 Y軸設定
        '    .HasTitle = True
        '    .AxisTitle.Text = "自營商"              '右邊 Y軸名稱
        '    .AxisTitle.Font.Size = 12
        '    .AxisTitle.Orientation = xlVertical     '字體方向旋轉
        '    .AxisTitle.VerticalAlignment = xlCenter
        '    .AxisTitle.HorizontalAlignment = xlCenter
        'End With
    End With
End Sub

Sub ClaerChartObjects()
    Dim Chtobj As ChartObject
    
    For Each Chtobj In ActiveSheet.ChartObjects
        Chtobj.Delete
    Next
End Sub
執行結果

沒有留言:

張貼留言