62 lines
1.8 KiB
Bash
62 lines
1.8 KiB
Bash
#!/bin/bash
|
|
|
|
psql --username "$POSTGRES_USER" --dbname "$POSTGRES_DB" <<-EOSQL
|
|
CREATE TYPE CLASS AS ENUM ('us_equity', 'crypto');
|
|
|
|
CREATE TYPE EXCHANGE AS ENUM (
|
|
'AMEX',
|
|
'ARCA',
|
|
'BATS',
|
|
'NASDAQ',
|
|
'NYSE',
|
|
'NYSEARCA',
|
|
'OTC',
|
|
'CRYPTO'
|
|
);
|
|
|
|
CREATE TABLE assets (
|
|
symbol TEXT PRIMARY KEY,
|
|
class CLASS NOT NULL,
|
|
exchange EXCHANGE NOT NULL,
|
|
trading BOOLEAN NOT NULL DEFAULT FALSE,
|
|
date_added TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
CREATE TABLE bars (
|
|
timestamp TIMESTAMPTZ NOT NULL,
|
|
asset_symbol TEXT NOT NULL REFERENCES assets(symbol) ON DELETE CASCADE ON UPDATE CASCADE,
|
|
open DOUBLE PRECISION NOT NULL,
|
|
high DOUBLE PRECISION NOT NULL,
|
|
low DOUBLE PRECISION NOT NULL,
|
|
close DOUBLE PRECISION NOT NULL,
|
|
volume DOUBLE PRECISION NOT NULL,
|
|
num_trades BIGINT NOT NULL,
|
|
volume_weighted DOUBLE PRECISION NOT NULL,
|
|
PRIMARY KEY (asset_symbol, timestamp)
|
|
);
|
|
|
|
SELECT create_hypertable('bars', 'timestamp', 'asset_symbol', 2);
|
|
|
|
CREATE TABLE calendar (
|
|
date DATE NOT NULL PRIMARY KEY,
|
|
open TIME NOT NULL,
|
|
close TIME NOT NULL
|
|
);
|
|
|
|
CREATE VIEW bars_missing AS
|
|
WITH time_series AS (
|
|
SELECT
|
|
asset_symbol,
|
|
generate_series(MIN(timestamp), NOW(), interval '1 minute')::TIMESTAMPTZ AS expected_time
|
|
FROM bars
|
|
GROUP BY asset_symbol
|
|
)
|
|
SELECT
|
|
ts.asset_symbol,
|
|
ts.expected_time AS missing_time
|
|
FROM time_series ts
|
|
LEFT JOIN bars b
|
|
ON ts.asset_symbol = b.asset_symbol AND ts.expected_time = b.timestamp
|
|
WHERE b.timestamp IS NULL;
|
|
EOSQL
|