You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

334 lines
15KB

  1. SELECT hr,
  2. bmex / gdax AS ratio
  3. FROM
  4. (SELECT hr,
  5. max(gdax) "gdax", -- max(..) necessary to grab the non-NULL row from two returned
  6. max(bmex) "bmex" -- rows for each hr
  7. FROM
  8. (SELECT hr,
  9. (CASE WHEN exch=3 THEN wt_avg END) "gdax",
  10. (CASE WHEN exch=6 THEN wt_avg END) "bmex"
  11. FROM
  12. (SELECT hr,
  13. exch,
  14. w_sum / sum_w AS wt_avg
  15. FROM
  16. (SELECT date_trunc('hour', "time") AS hr,
  17. exch,
  18. sum(price * amount) AS w_sum,
  19. sum(amount) AS sum_w
  20. FROM trades
  21. WHERE base=1 -- btc=1 usd=100
  22. AND quote=100
  23. AND (exch=3 OR exch=6) -- gdax=3, bmex=6
  24. GROUP BY 1, 2
  25. ORDER BY 1, 2) a) b) c
  26. GROUP BY hr) d;
  27. SELECT hr,
  28. base,
  29. quote,
  30. bmex / gdax AS bmex_gdax,
  31. bmex / btfx AS bmex_btfx,
  32. bmex / bits AS bmex_bits,
  33. bmex / bnce AS bmex_bnce,
  34. bmex / okex AS bmex_okex,
  35. bmex / plnx AS bmex_plnx
  36. FROM
  37. (SELECT hr,
  38. base,
  39. quote,
  40. max(gdax) "gdax", -- max(..) necessary to grab the non-NULL row from two returned
  41. max(bmex) "bmex", -- rows for each hr
  42. max(btfx) "btfx",
  43. max(bnce) "bnce",
  44. max(okex) "okex",
  45. max(plnx) "plnx",
  46. max(bits) "bits"
  47. FROM
  48. (SELECT hr,
  49. base,
  50. quote,
  51. (CASE WHEN exch=1 THEN wt_avg END) "plnx",
  52. (CASE WHEN exch=3 THEN wt_avg END) "gdax",
  53. (CASE WHEN exch=5 THEN wt_avg END) "bits",
  54. (CASE WHEN exch=6 THEN wt_avg END) "bmex",
  55. (CASE WHEN exch=7 THEN wt_avg END) "btfx",
  56. (CASE WHEN exch=8 THEN wt_avg END) "bnce",
  57. (CASE WHEN exch=9 THEN wt_avg END) "okex"
  58. FROM
  59. (SELECT hr,
  60. exch,
  61. base,
  62. quote,
  63. w_sum / sum_w AS wt_avg
  64. FROM
  65. (SELECT date_trunc('hour', "time") AS hr,
  66. exch,
  67. base,
  68. quote,
  69. sum(price * amount) AS w_sum,
  70. sum(amount) AS sum_w
  71. FROM trades
  72. WHERE
  73. -- base=1 -- btc=1 usd=100
  74. -- AND quote=100
  75. -- AND
  76. exch IN (1,3,5,6,7,8,9)
  77. GROUP BY 1, 2, 3, 4
  78. ORDER BY 1, 2, 3, 4) a) b) c
  79. GROUP BY hr, base, quote) d;
  80. SELECT tm,
  81. bmex / gdax AS ratio
  82. FROM
  83. (SELECT tm,
  84. max(gdax) "gdax", -- max(..) necessary to grab the non-NULL row from two returned
  85. max(bmex) "bmex" -- rows for each tm
  86. FROM
  87. (SELECT tm,
  88. (CASE WHEN exch=3 THEN wt_avg END) "gdax",
  89. (CASE WHEN exch=6 THEN wt_avg END) "bmex"
  90. FROM
  91. (SELECT tm,
  92. exch,
  93. w_sum / sum_w AS wt_avg
  94. FROM
  95. (SELECT
  96. -- date_trunc('minute', "time") AS tm,
  97. date_trunc('minute', "time") - (CAST(EXTRACT(MINUTE FROM "time") AS integer) % 10) * interval '1 minute' AS tm,
  98. exch,
  99. sum(price * amount) AS w_sum,
  100. sum(amount) AS sum_w
  101. FROM trades
  102. WHERE base=1 -- btc=1 usd=100
  103. AND quote=100
  104. AND (exch=3 OR exch=6) -- gdax=3, bmex=6
  105. GROUP BY 1, 2
  106. ORDER BY 1, 2) a) b) c
  107. GROUP BY tm) d;
  108. select tm from generate_series('2019-01-01T00:00:00Z'::timestamptz, '2019-02-01T00:00:00Z'::timestamptz, interval '1 second') as tm;
  109. select tm,
  110. sum(d1.price * d1.amount) / sum(d1.amount) as d1_wt_avg_price,
  111. sum(d1bmex.price * d1bmex.amount) / sum(d1bmex.amount) as d1bmex_wt_avg_price,
  112. sum(d5.price * d5.amount) / sum(d5.amount) as d5_wt_avg_price,
  113. sum(d5bmex.price * d5bmex.amount) / sum(d5bmex.amount) as d5bmex_wt_avg_price
  114. from
  115. (select tm::timestamptz from generate_series(
  116. (select date_trunc('second', min("time")) from trades) + '20 minutes'::interval,
  117. -- (select date_trunc('second', max("time")) from trades),
  118. (select date_trunc('second', min("time")) from trades) + '21 minutes'::interval,
  119. interval '1 second'
  120. ) as tm
  121. ) a
  122. left join trades d1 on (d1.time between a.tm - '1 minute'::interval and a.tm and d1.base=1 and d1.quote=100 and d1.exch=3)
  123. left join trades d1bmex on (d1bmex.time between a.tm - '1 minute'::interval and a.tm and d1bmex.base=1 and d1bmex.quote=100 and d1bmex.exch=6)
  124. left join trades d5 on (d5.time between a.tm - '5 minute'::interval and a.tm and d5.base=1 and d5.quote=100 and d5.exch=3)
  125. left join trades d5bmex on (d5bmex.time between a.tm - '5 minute'::interval and a.tm and d5bmex.base=1 and d5bmex.quote=100 and d5bmex.exch=6)
  126. group by a.tm
  127. order by a.tm;
  128. -- left join lateral (
  129. -- select sum(price * amount) as wsum, sum(amount) as w
  130. -- from trades
  131. -- where base=1 and quote=100
  132. -- group by exch
  133. --inner join (select "time", price, amount from trades where base=1 and quote=100 and exch=3) d1
  134. -- on (d1."time" between a.tm - '1 minute'::interval and a.tm)
  135. -- on 1
  136. -- inner join (select "time", sum(price * amount) as w_sum, sum(amount) as sum_w from trades group by exch) d5
  137. -- inner join (select sum(price * amount) as w_sum, sum(amount) as sum_w from trades where "time" between a.tm - '5 minute'::interval and a.tm and base=1 and quote=100 and exch in (3,6) group by exch) d5
  138. -- on 1
  139. -- on (d5."time" between a.tm - '5 minutes'::interval and a.tm)
  140. -- where
  141. -- d1.base = 1
  142. -- and d1.quote = 100
  143. -- and d5.base = 1
  144. -- and d5.quote = 100
  145. -- and d1.exch in (3,6)
  146. -- and d5.exch in (3,6)
  147. ;
  148. select
  149. tm,
  150. bmex_d15_wt_avg_price / gdax_d15_wt_avg_price as ratio_15,
  151. bmex_d60_wt_avg_price / gdax_d60_wt_avg_price as ratio_60
  152. from (
  153. select tm,
  154. sum(gdax_d15.price * gdax_d15.amount) / sum(gdax_d15.amount) as gdax_d15_wt_avg_price,
  155. sum(bmex_d15.price * bmex_d15.amount) / sum(bmex_d15.amount) as bmex_d15_wt_avg_price,
  156. sum(gdax_d60.price * gdax_d60.amount) / sum(gdax_d60.amount) as gdax_d60_wt_avg_price,
  157. sum(bmex_d60.price * bmex_d60.amount) / sum(bmex_d60.amount) as bmex_d60_wt_avg_price
  158. from
  159. (select tm::timestamptz from generate_series(
  160. (select date_trunc('second', min("time")) from trades) + '2 hours'::interval,
  161. (select date_trunc('second', min("time")) from trades) + '2 hours'::interval + '10 second'::interval,
  162. -- (select date_trunc('second', max("time")) from trades),
  163. interval '1 second'
  164. ) as tm
  165. ) a
  166. join trades gdax_d15 on (gdax_d15.time > a.tm - '15 minutes'::interval and gdax_d15.time <= a.tm and gdax_d15.base=1 and gdax_d15.quote=100 and gdax_d15.exch=3)
  167. join trades bmex_d15 on (bmex_d15.time > a.tm - '15 minutes'::interval and bmex_d15.time <= a.tm and bmex_d15.base=1 and bmex_d15.quote=100 and bmex_d15.exch=6)
  168. join trades gdax_d60 on (gdax_d60.time > a.tm - '60 minutes'::interval and gdax_d60.time <= a.tm and gdax_d60.base=1 and gdax_d60.quote=100 and gdax_d60.exch=3)
  169. join trades bmex_d60 on (bmex_d60.time > a.tm - '60 minutes'::interval and bmex_d60.time <= a.tm and bmex_d60.base=1 and bmex_d60.quote=100 and bmex_d60.exch=6)
  170. group by a.tm
  171. order by a.tm
  172. ) b;
  173. SELECT tm,
  174. bmex / gdax AS ratio
  175. FROM
  176. (SELECT tm,
  177. max(gdax) "gdax", -- max(..) necessary to grab the non-NULL row from two returned
  178. max(bmex) "bmex" -- rows for each tm
  179. FROM
  180. GROUP BY tm) d;
  181. SELECT
  182. tm,
  183. max(gdax_w_sum) "gdax_w_sum",
  184. max(gdax_sum_w) "gdax_sum_w",
  185. max(bmex_w_sum) "bmex_w_sum",
  186. max(bmex_sum_w) "bmex_sum_w"
  187. FROM
  188. (SELECT tm,
  189. (CASE WHEN exch=3 THEN w_sum END) "gdax_w_sum",
  190. (CASE WHEN exch=3 THEN sum_w END) "gdax_sum_w",
  191. (CASE WHEN exch=6 THEN w_sum END) "bmex_w_sum",
  192. (CASE WHEN exch=6 THEN sum_w END) "bmex_sum_w"
  193. FROM
  194. (SELECT date_trunc('second', "time") AS tm,
  195. exch,
  196. sum(price * amount) AS w_sum,
  197. sum(amount) AS sum_w
  198. FROM trades
  199. WHERE base=1 -- btc=1 usd=100
  200. AND quote=100
  201. AND (exch=3 OR exch=6) -- gdax=3, bmex=6
  202. GROUP BY 1, 2
  203. ORDER BY 1, 2) a) b
  204. GROUP BY tm
  205. ORDER BY tm
  206. ;
  207. SELECT a."time", avg(b.price)
  208. FROM trades a
  209. JOIN trades b ON b.time >= a.time - interval '1 minute'
  210. AND b.time <= a.time
  211. GROUP BY a.time
  212. ORDER BY a.time
  213. limit 10;
  214. select
  215. tm,
  216. bmex_d15_wt_avg_price / gdax_d15_wt_avg_price as ratio_15,
  217. bmex_d5_wt_avg_price / gdax_d5_wt_avg_price as ratio_5
  218. from (
  219. select tm,
  220. sum(gdax_d15.price * gdax_d15.amount) / sum(gdax_d15.amount) as gdax_d15_wt_avg_price,
  221. sum(bmex_d15.price * bmex_d15.amount) / sum(bmex_d15.amount) as bmex_d15_wt_avg_price,
  222. sum(gdax_d5.price * gdax_d5.amount) / sum(gdax_d5.amount) as gdax_d5_wt_avg_price,
  223. sum(bmex_d5.price * bmex_d5.amount) / sum(bmex_d5.amount) as bmex_d5_wt_avg_price
  224. from
  225. (select tm::timestamptz from generate_series(
  226. (select date_trunc('second', min("time")) from trades limit 1), -- + '2 hours'::interval,
  227. -- (select date_trunc('second', min("time")) from trades) + '2 hours, 2 seconds'::interval,
  228. (select date_trunc('second', max("time")) from trades limit 1),
  229. interval '1 second'
  230. ) as tm
  231. ) a
  232. join trades gdax_d15 on (gdax_d15.time > a.tm - '15 minutes'::interval and gdax_d15.time <= a.tm and gdax_d15.base=1 and gdax_d15.quote=100 and gdax_d15.exch=3)
  233. join trades bmex_d15 on (bmex_d15.time > a.tm - '15 minutes'::interval and bmex_d15.time <= a.tm and bmex_d15.base=1 and bmex_d15.quote=100 and bmex_d15.exch=6)
  234. join trades gdax_d5 on (gdax_d5.time > a.tm - '5 minutes'::interval and gdax_d5.time <= a.tm and gdax_d5.base=1 and gdax_d5.quote=100 and gdax_d5.exch=3)
  235. join trades bmex_d5 on (bmex_d5.time > a.tm - '5 minutes'::interval and bmex_d5.time <= a.tm and bmex_d5.base=1 and bmex_d5.quote=100 and bmex_d5.exch=6)
  236. group by a.tm
  237. order by a.tm
  238. ) b;
  239. select "time", avg(price) filter(where "time" > "time" - interval '10 seconds' and "time" <= "time") over( order by "time" ) from trades order by "time" limit 10;
  240. select
  241. "time",
  242. -- (bmex_wsum_5 / bmex_w_5) as bmex_5min,
  243. -- (gdax_wsum_5 / gdax_w_5) as gdax_5min,
  244. (bmex_wsum_5 / bmex_w_5) / (gdax_wsum_5 / gdax_w_5 ) as r5,
  245. -- (bmex_wsum_15 / bmex_w_15) / (gdax_wsum_15 / gdax_w_15) as r15,
  246. -- (bmex_wsum_60 / bmex_w_60) / (gdax_wsum_60 / gdax_w_60) as r60
  247. from
  248. (select
  249. "time",
  250. sum(price * amount) filter(where "time" > "time" - interval '5 minutes' and "time" <= "time" and exch=3) over( order by "time" ) "gdax_wsum_5",
  251. -- sum(price * amount) filter(where "time" > "time" - interval '15 minutes' and "time" <= "time" and exch=3) over( order by "time" ) "gdax_wsum_15",
  252. -- sum(price * amount) filter(where "time" > "time" - interval '60 minutes' and "time" <= "time" and exch=3) over( order by "time" ) "gdax_wsum_60",
  253. sum(amount) filter(where "time" > "time" - interval '5 minutes' and "time" <= "time" and exch=3) over( order by "time" ) "gdax_w_5",
  254. -- sum(amount) filter(where "time" > "time" - interval '15 minutes' and "time" <= "time" and exch=3) over( order by "time" ) "gdax_w_15",
  255. -- sum(amount) filter(where "time" > "time" - interval '60 minutes' and "time" <= "time" and exch=3) over( order by "time" ) "gdax_w_60",
  256. sum(price * amount) filter(where "time" > "time" - interval '5 minutes' and "time" <= "time" and exch=6) over( order by "time" ) "bmex_wsum_5",
  257. -- sum(price * amount) filter(where "time" > "time" - interval '15 minutes' and "time" <= "time" and exch=6) over( order by "time" ) "bmex_wsum_15",
  258. -- sum(price * amount) filter(where "time" > "time" - interval '60 minutes' and "time" <= "time" and exch=6) over( order by "time" ) "bmex_wsum_60",
  259. sum(amount) filter(where "time" > "time" - interval '5 minutes' and "time" <= "time" and exch=6) over( order by "time" ) "bmex_w_5"
  260. -- sum(amount) filter(where "time" > "time" - interval '15 minutes' and "time" <= "time" and exch=6) over( order by "time" ) "bmex_w_15",
  261. -- sum(amount) filter(where "time" > "time" - interval '60 minutes' and "time" <= "time" and exch=6) over( order by "time" ) "bmex_w_60"
  262. from trades
  263. order by "time") a
  264. ;
  265. with seconds as (
  266. select tm::timestamptz from generate_series(
  267. (select date_trunc('second', min("time")) from trades limit 1), -- + '2 hours'::interval,
  268. -- (select date_trunc('second', min("time")) from trades) + '2 hours, 2 seconds'::interval,
  269. (select date_trunc('second', max("time")) from trades limit 1),
  270. interval '1 second'
  271. ) as tm
  272. )
  273. select
  274. tm,
  275. (bmex_wsum_5 / bmex_w_5) / (gdax_wsum_5 / gdax_w_5 ) as r5,
  276. (bmex_wsum_15 / bmex_w_15) / (gdax_wsum_15 / gdax_w_15) as r15,
  277. (bmex_wsum_60 / bmex_w_60) / (gdax_wsum_60 / gdax_w_60) as r60
  278. from
  279. (select
  280. seconds.tm,
  281. sum(price * amount) filter(where "time" > seconds.tm - interval '5 minutes' and "time" <= seconds.tm and exch=3) over( order by "time" ) "gdax_wsum_5",
  282. sum(price * amount) filter(where "time" > seconds.tm - interval '15 minutes' and "time" <= seconds.tm and exch=3) over( order by "time" ) "gdax_wsum_15",
  283. sum(price * amount) filter(where "time" > seconds.tm - interval '60 minutes' and "time" <= seconds.tm and exch=3) over( order by "time" ) "gdax_wsum_60",
  284. sum(amount) filter(where "time" > seconds.tm - interval '5 minutes' and "time" <= seconds.tm and exch=3) over( order by "time" ) "gdax_w_5",
  285. sum(amount) filter(where "time" > seconds.tm - interval '15 minutes' and "time" <= seconds.tm and exch=3) over( order by "time" ) "gdax_w_15",
  286. sum(amount) filter(where "time" > seconds.tm - interval '60 minutes' and "time" <= seconds.tm and exch=3) over( order by "time" ) "gdax_w_60",
  287. sum(price * amount) filter(where "time" > seconds.tm - interval '5 minutes' and "time" <= seconds.tm and exch=6) over( order by "time" ) "bmex_wsum_5",
  288. sum(price * amount) filter(where "time" > seconds.tm - interval '15 minutes' and "time" <= seconds.tm and exch=6) over( order by "time" ) "bmex_wsum_15",
  289. sum(price * amount) filter(where "time" > seconds.tm - interval '60 minutes' and "time" <= seconds.tm and exch=6) over( order by "time" ) "bmex_wsum_60",
  290. sum(amount) filter(where "time" > seconds.tm - interval '5 minutes' and "time" <= seconds.tm and exch=6) over( order by "time" ) "bmex_w_5",
  291. sum(amount) filter(where "time" > seconds.tm - interval '15 minutes' and "time" <= seconds.tm and exch=6) over( order by "time" ) "bmex_w_15",
  292. sum(amount) filter(where "time" > seconds.tm - interval '60 minutes' and "time" <= seconds.tm and exch=6) over( order by "time" ) "bmex_w_60"
  293. from seconds, trades
  294. -- order by seconds.tm) a
  295. ) a
  296. limit 1000;