Google Script - REST API Private Endpoints

Our REST API authenticated endpoints are accessible via a simple HTTP request (just as a web page is requested via a web browser), so an API client to import market data into a Google Sheet can be implemented with just a few lines of Google Script code.

Installation

  1. 1

    Create a new Google Sheet or open an existing sheet.

  2. 2

    Open the script editor via the Extensions -> Apps Script menu.

  3. 3

    Delete the default code that is shown (Select All then Delete/Backspace, for example).

  4. 4

    Copy/Paste the Google Script API code (shown below) into the script editor.

  5. 5

    Update the example API key to use an API key from your Kraken account.

  6. 6

    Optional - Add any additional custom functions that you require (to call different endpoints, or return different JSON fields, for example).

  7. 7

    Save the Google Script Code via the

    (Save project) icon.

    Save Icon

SaveImageIcon

Usage

The KAPI_Private() function is responsible for creating the appropriate URL, calculating the authentication signature, and making the HTTP request to the API. The KAPI_Private() function can be called directly by entering the following (or similar depending upon the account ID, the endpoint, and the parameters) within a Google Sheet cell:

bash

Bash

=KAPI_Private("TEST", "Balance", "")

=KAPI_Private("TEST", "TradeBalance", "asset=xdg")

=KAPI_Private("TEST", "OpenOrders", "userref=886794735")

The KAPI_Private() function returns the original JSON response from the API, such as the following for the above Balance endpoint example:

bash

Bash

{"error":[],"result":{"ZUSD":"16.4272","ZEUR":"0.3880","ZJPY":"0.45","KFEE":"10368.39","XXBT":"0.0000000072","XXRP":"0.00000000","XLTC":"0.0000000100","XXDG":"13997.00000000","XXLM":"100.00000000"}}

In order to place the individual fields/values into separate cells within the Google Sheet, additional custom functions can be called to parse the JSON response, such as the example KAPI_Balance() and KAPI_OpenOrders() functions:

  • =KAPI_Balance("TEST")

  • =KAPI_OpenOrders("TEST")

bash

Bash

=KAPI_Balance("TEST")

=KAPI_OpenOrders("TEST")

This would display the results similar to the following, where the data would be accessible to any of the standard Google Sheets functions (SUM, AVERAGE, COUNT, etc.):

API_GoogleSheetOutputEndpoints_10062020.png

Google Script Code For Private Endpoints:

Authentication Algorithm:

bash

Bash

API_Public_Key = { 
  'TEST': 'INSERT YOUR API PUBLIC KEY' 
}

API_Private_Key = { 
  'TEST': 'INSERT YOUR API PRIVATE KEY' 
}

function KAPI_Private(acc_id, endpoint, parameters) {
  Utilities.sleep(Math.random() * 100)

  api_key = API_Public_Key[acc_id]
  api_secret = Utilities.base64Decode(API_Private_Key[acc_id])
  api_path = Utilities.newBlob('/0/private/' + endpoint).getBytes()
  api_nonce = Date.now().toString()
  api_post = 'nonce=' + api_nonce + '&' + parameters

  api_sha256 = Utilities.computeDigest(
    Utilities.DigestAlgorithm.SHA_256, 
    api_nonce + api_post
  )
  api_hmac = Utilities.computeHmacSignature(
    Utilities.MacAlgorithm.HMAC_SHA_512, 
    api_path.concat(api_sha256), 
    api_secret
  )
  api_signature = Utilities.base64Encode(api_hmac)

  http_options = {
    'method': 'post', 
    'payload': api_post, 
    'headers': {
      'API-Key': api_key, 
      'API-Sign': api_signature
    }
  }
  http_response = UrlFetchApp.fetch(
    'https://api.kraken.com/0/private/' + endpoint, 
    http_options
  )
  api_data = http_response.getContentText()
  return api_data
}

To use the following scripts with the Authentication Algorithm above, simply append the function to the script above.

*Please note that all Private Endpoints require the implementation of the Authentication Algorithm.*

Balance:

bash

Bash

// Formula to use in Excel cell: '=KAPI_Balance("TEST")
function KAPI_Balance(acc_id) {
  acc_balances_json = JSON.parse(
    KAPI_Private(acc_id, 'Balance', '')
  )
  acc_balances = new Array()
  for (name in acc_balances_json['result']) {
    acc_balances.push([
      name, 
      parseFloat(acc_balances_json['result'][name])
    ])
  }
  return acc_balances
}

Extended Balance:

bash

Bash

// Formula to use in Excel cell: '=KAPI_BalanceEx("TEST")

function KAPI_BalanceEx(acc_id) {
  acc_balances_json = JSON.parse(KAPI_Private(acc_id, 'BalanceEx', ''))
  acc_balances = new Array
  for (name in acc_balances_json['result']) {
    acc_balances.push([
      name,
      parseFloat(acc_balances_json['result'][name]['balance']),
      parseFloat(acc_balances_json['result'][name]['hold_trade']),
      parseFloat(acc_balances_json['result'][name]['credit'] ? acc_balances_json['result'][name]['credit'] : '') || 0,
      parseFloat(acc_balances_json['result'][name]['credit_used'] ? acc_balances_json['result'][name]['credit_used'] : '') || 0
    ]);
  }
  return acc_balances
}

Trade Balance:

bash

Bash

// Formula to use in Excel cell: '=KAPI_TradeBalance("TEST", "ASSET")'

function KAPI_TradeBalance(acc_id, currency) {
  acc_balances_json = JSON.parse(
    KAPI_Private(acc_id, 'TradeBalance', 'asset=' + currency)
  )
  acc_balances = new Array()
  for (name in acc_balances_json['result']) {
    acc_balances.push([
      name, 
      parseFloat(acc_balances_json['result'][name])
    ])
  }
  return acc_balances
}

Open Orders:

bash

Bash

// Formula to use in Excel cell: '=KAPI_Private("TEST","OpenOrders","")'

function KAPI_OpenOrders(acc_id) {
  acc_orders_json = JSON.parse(
    KAPI_Private(acc_id, 'OpenOrders', '')
  )
  acc_orders = new Array()
  for (name in acc_orders_json['result']['open']) {
    acc_orders.push([
      name, 
      acc_orders_json['result']['open'][name]['descr']['pair'], 
      acc_orders_json['result']['open'][name]['descr']['type'], 
      parseFloat(acc_orders_json['result']['open'][name]['descr']['price']), 
      parseFloat(acc_orders_json['result']['open'][name]['vol']), 
      parseFloat(acc_orders_json['result']['open'][name]['vol_exec']), 
      parseFloat(acc_orders_json['result']['open'][name]['opentm'])
    ])
  }
  return acc_orders
}

Closed Orders:

bash

Bash

// Formula to use in Excel cell: '=KAPI_ClosedOrders("TEST","0")'
// Or =KAPI_PRIVATE("TEST","ClosedOrders","0")

function KAPI_ClosedOrders(acc_id, offset) {
  acc_orders_json = JSON.parse(
    KAPI_Private(acc_id, 'ClosedOrders', 'ofs=' + offset)
  )
  acc_orders = new Array()
  for (name in acc_orders_json['result']['closed']) {
    acc_orders.push([
      name, 
      acc_orders_json['result']['closed'][name]['descr']['pair'], 
      acc_orders_json['result']['closed'][name]['descr']['type'], 
      acc_orders_json['result']['closed'][name]['descr']['ordertype'], 
      acc_orders_json['result']['closed'][name]['descr']['price'], 
      acc_orders_json['result']['closed'][name]['descr']['order'], 
      acc_orders_json['result']['closed'][name]['price'], 
      acc_orders_json['result']['closed'][name]['vol'], 
      acc_orders_json['result']['closed'][name]['vol_exec'], 
      acc_orders_json['result']['closed'][name]['cost'], 
      acc_orders_json['result']['closed'][name]['fee'], 
      acc_orders_json['result']['closed'][name]['status']
    ])
  }
  return acc_orders
}

TradesHistory:

bash

Bash

// Formula to be used in Excel cell '=KAPI_TradesHistory("TEST","0")'

function KAPI_TradesHistory(acc_id, offset) {
  acc_trades_json = JSON.parse(KAPI_Private(acc_id, 'TradesHistory', 'ofs=' + offset))
  acc_trades = new Array
for (name in acc_trades_json['result']['trades']) {
  acc_trades.push([
    name,
    acc_trades_json['result']['trades'][name]['ordertxid'],
    acc_trades_json['result']['trades'][name]['postxid'],
    acc_trades_json['result']['trades'][name]['pair'],
    acc_trades_json['result']['trades'][name]['time'],
    acc_trades_json['result']['trades'][name]['type'],
    acc_trades_json['result']['trades'][name]['ordertype'],
    acc_trades_json['result']['trades'][name]['price'],
    acc_trades_json['result']['trades'][name]['cost'],
    acc_trades_json['result']['trades'][name]['fee'],
    acc_trades_json['result']['trades'][name]['vol'],
    acc_trades_json['result']['trades'][name]['margin'],
    acc_trades_json['result']['trades'][name]['leverage'],
    acc_trades_json['result']['trades'][name]['misc'],
    acc_trades_json['result']['trades'][name]['trade_id'],
    acc_trades_json['result']['trades'][name]['maker']
    
  ])
}
return acc_trades
}

Open Positions:

bash

Bash

//Formula to use in Excel Cell '=KAPI_Private("TEST", "OpenPositions", "docalcs=true")'

function KAPI_OpenPositions(acc_id) {
  acc_positions_json = JSON.parse(
    KAPI_Private(acc_id, 'OpenPositions', 'docalcs=true')
  )
  acc_positions = new Array()
  for (name in acc_positions_json['result']) {
    acc_positions.push([
      name, 
      acc_positions_json['result'][name]['ordertxid'], 
      acc_positions_json['result'][name]['posstatus'], 
      acc_positions_json['result'][name]['pair'], 
      acc_positions_json['result'][name]['type'], 
      acc_positions_json['result'][name]['ordertype'], 
      acc_positions_json['result'][name]['cost'], 
      acc_positions_json['result'][name]['fee'], 
      acc_positions_json['result'][name]['vol'], 
      acc_positions_json['result'][name]['vol_closed'], 
      acc_positions_json['result'][name]['margin'], 
      acc_positions_json['result'][name]['value'], 
      acc_positions_json['result'][name]['net'], 
      acc_positions_json['result'][name]['time']
    ])
  }
  return acc_positions
}


Ledgers:

bash

Bash

//Formula to use in Excel Cell '=KAPI_Ledgers("TEST", "0")'


function KAPI_Ledgers(acc_id, offset) {
  acc_ledgers_json = JSON.parse(KAPI_Private(acc_id, 'Ledgers', 'ofs=' + offset))
  acc_ledgers = new Array
  for ( name in acc_ledgers_json['result']['ledger'] ) {
     acc_ledgers.push([name, acc_ledgers_json['result']['ledger'][name]['refid'], acc_ledgers_json['result']['ledger'][name]['time'], acc_ledgers_json['result']['ledger'][name]['type'], acc_ledgers_json['result']['ledger'][name]['subtype'], acc_ledgers_json['result']['ledger'][name]['asset'], acc_ledgers_json['result']['ledger'][name]['amount'], acc_ledgers_json['result']['ledger'][name]['fee'], acc_ledgers_json['result']['ledger'][name]['balance']])
  }
  return acc_ledgers
}

Query Order Info:

bash

Bash

// Formula to use in Excel cell '=KAPI_QueryOrders("TEST","Order ID")'

function KAPI_QueryOrders(acc_id, order_id) {
  acc_orders_json = JSON.parse(
    KAPI_Private(acc_id, 'QueryOrders', 'txid=' + order_id)
  )
  acc_orders = new Array()
  for (name in acc_orders_json['result']) {
    acc_orders.push([
      name, 
      acc_orders_json['result'][name]['descr']['pair'], 
      acc_orders_json['result'][name]['descr']['type'], 
      acc_orders_json['result'][name]['descr']['ordertype'], 
      acc_orders_json['result'][name]['descr']['price'], 
      acc_orders_json['result'][name]['descr']['order'], 
      acc_orders_json['result'][name]['price'], 
      acc_orders_json['result'][name]['vol'], 
      acc_orders_json['result'][name]['vol_exec'], 
      acc_orders_json['result'][name]['cost'], 
      acc_orders_json['result'][name]['fee'], 
      acc_orders_json['result'][name]['status']
    ])
  }
  return acc_orders
}

Example of a full Google Script function that calls on the TradesHistory endpoint:

bash

Bash

const API_Public_Key = { 'TEST':'API PUBLIC KEY'}
const API_Private_Key = { 'TEST':'API PRIVATe KEY' }


function KAPI_Private(acc_id, endpoint, parameters) {
  Utilities.sleep(Math.random() * 100)
  
  api_key = API_Public_Key[acc_id]
  api_secret = Utilities.base64Decode(API_Private_Key[acc_id])
  api_path = Utilities.newBlob('/0/private/' + endpoint).getBytes()
  api_nonce = Date.now().toString()
  api_post = 'nonce=' + api_nonce + '&' + parameters
  
  api_sha256 = Utilities.computeDigest(Utilities.DigestAlgorithm.SHA_256, api_nonce + api_post)
  api_hmac = Utilities.computeHmacSignature(Utilities.MacAlgorithm.HMAC_SHA_512, api_path.concat(api_sha256), api_secret)
  api_signature = Utilities.base64Encode(api_hmac)
  
  http_options = {'method':'post', 'payload':api_post, 'headers':{'API-Key':api_key, 'API-Sign':api_signature}}
  http_response = UrlFetchApp.fetch('https://api.kraken.com/0/private/' + endpoint, http_options)
  api_data = http_response.getContentText()
  return api_data
}



function KAPI_TradesHistory(acc_id, offset) {
  acc_trades_json = JSON.parse(KAPI_Private(acc_id, 'TradesHistory', 'ofs=' + offset))
  acc_trades = new Array
for (name in acc_trades_json['result']['trades']) {
  acc_trades.push([
    name,
    acc_trades_json['result']['trades'][name]['ordertxid'],
    acc_trades_json['result']['trades'][name]['postxid'],
    acc_trades_json['result']['trades'][name]['pair'],
    acc_trades_json['result']['trades'][name]['time'],
    acc_trades_json['result']['trades'][name]['type'],
    acc_trades_json['result']['trades'][name]['ordertype'],
    acc_trades_json['result']['trades'][name]['price'],
    acc_trades_json['result']['trades'][name]['cost'],
    acc_trades_json['result']['trades'][name]['fee'],
    acc_trades_json['result']['trades'][name]['vol'],
    acc_trades_json['result']['trades'][name]['margin'],
    acc_trades_json['result']['trades'][name]['leverage'],
    acc_trades_json['result']['trades'][name]['misc'],
    acc_trades_json['result']['trades'][name]['trade_id'],
    acc_trades_json['result']['trades'][name]['maker']
    
  ])
}
return acc_trades
}

The decimal and thousands separators shown in this article may differ from the formats displayed on our trading platforms. Review our article on how we use points and commas for more information.

test

Installation
Usage
Google Script Code For Private Endpoints:

Need more help?