You cannot select more than 25 topics
Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
219 lines
5.8 KiB
SQL
219 lines
5.8 KiB
SQL
CREATE TABLE symbols
|
|
(
|
|
symbol String,
|
|
name String,
|
|
sector LowCardinality(String),
|
|
subindustry LowCardinality(String),
|
|
headquarters_location String,
|
|
date_added Date,
|
|
cik UInt32,
|
|
year_founded String
|
|
)
|
|
ENGINE MergeTree()
|
|
ORDER BY (symbol);
|
|
|
|
CREATE TABLE option_contract_existences
|
|
(
|
|
asOfDate Date,
|
|
symbol LowCardinality(String),
|
|
expirationDate Date,
|
|
strike Float32,
|
|
type ENUM('call', 'put')
|
|
)
|
|
ENGINE ReplacingMergeTree()
|
|
PRIMARY KEY (asOfDate, symbol)
|
|
ORDER BY (asOfDate, symbol, expirationDate, strike, type);
|
|
|
|
CREATE TABLE option_contracts
|
|
(
|
|
symbol LowCardinality(String),
|
|
expirationDate Date,
|
|
strike Float32,
|
|
type ENUM('call', 'put')
|
|
)
|
|
ENGINE ReplacingMergeTree()
|
|
PRIMARY KEY (symbol, expirationDate)
|
|
ORDER BY (symbol, expirationDate, strike, type);
|
|
|
|
CREATE MATERIALIZED VIEW option_contracts_mv
|
|
TO option_contracts
|
|
AS
|
|
SELECT
|
|
DISTINCT ON (
|
|
symbol,
|
|
expirationDate,
|
|
strike,
|
|
type
|
|
)
|
|
symbol,
|
|
expirationDate,
|
|
strike,
|
|
type
|
|
FROM option_contract_existences;
|
|
|
|
|
|
-- BEGIN: Option Contract Quotes
|
|
|
|
-- END: Option Contract Quotes
|
|
|
|
CREATE TABLE stock_aggregates
|
|
(
|
|
symbol LowCardinality(String),
|
|
tsStart DateTime32,
|
|
open Float64,
|
|
close Float64,
|
|
low Float64,
|
|
high Float64,
|
|
volume UInt64,
|
|
volume_weighted_price Float64
|
|
)
|
|
ENGINE MergeTree()
|
|
ORDER BY (symbol, tsStart)
|
|
|
|
CREATE TABLE option_aggregates
|
|
(
|
|
symbol LowCardinality(String),
|
|
expirationDate Date,
|
|
strike Float32,
|
|
type Enum('call', 'put'),
|
|
|
|
tsStart DateTime32 CODEC(DoubleDelta(1), ZSTD),
|
|
open Float32 CODEC(Delta(2), ZSTD),
|
|
close Float32 CODEC(Delta(2), ZSTD),
|
|
low Float32 CODEC(Delta(2), ZSTD),
|
|
high Float32 CODEC(Delta(2), ZSTD),
|
|
volume UInt32 CODEC(T64),
|
|
volumeWeightedPrice Float32 CODEC(Delta(2), ZSTD)
|
|
)
|
|
ENGINE MergeTree()
|
|
ORDER BY (symbol, expirationDate, strike, type, tsStart)
|
|
|
|
ALTER TABLE option_aggregates ADD INDEX idx_expirationDate expirationDate TYPE minmax GRANULARITY 2;
|
|
ALTER TABLE option_aggregates ADD INDEX idx_strike strike TYPE minmax GRANULARITY 2;
|
|
ALTER TABLE option_aggregates ADD INDEX idx_tsStart tsStart TYPE minmax GRANULARITY 2;
|
|
|
|
CREATE TABLE option_contract_aggregates
|
|
(
|
|
symbol LowCardinality(String),
|
|
expirationDate Date,
|
|
strike Float32,
|
|
type Enum('call', 'put'),
|
|
|
|
tsStart DateTime32 CODEC(DoubleDelta(1), ZSTD),
|
|
open Float32 CODEC(Delta(2), ZSTD),
|
|
close Float32 CODEC(Delta(2), ZSTD),
|
|
low Float32 CODEC(Delta(2), ZSTD),
|
|
high Float32 CODEC(Delta(2), ZSTD),
|
|
volume UInt32 CODEC(T64),
|
|
volumeWeightedPrice Float32 CODEC(Delta(2), ZSTD)
|
|
)
|
|
ENGINE ReplacingMergeTree()
|
|
ORDER BY (symbol, expirationDate, strike, type, tsStart)
|
|
|
|
CREATE TABLE option_histories_last_day
|
|
(
|
|
symbol LowCardinality(String),
|
|
expirationDate Date,
|
|
strike Float64,
|
|
type Enum('call', 'put'),
|
|
|
|
tsStart DateTime32,
|
|
open Float64,
|
|
minutesToFront UInt16,
|
|
underlyingPrice Float64,
|
|
strikePercentageFromUnderlyingPrice Float64
|
|
)
|
|
ENGINE MergeTree()
|
|
ORDER BY (symbol, minutesToFront, strikePercentageFromUnderlyingPrice)
|
|
|
|
INSERT INTO option_histories_last_day
|
|
SELECT
|
|
option_aggregates.symbol as symbol,
|
|
option_aggregates.expirationDate as expirationDate,
|
|
option_aggregates.strike as strike,
|
|
option_aggregates.type as type,
|
|
option_aggregates.tsStart as tsStart,
|
|
option_aggregates.open as open,
|
|
date_diff('minute', tsStart, timestamp_add(expirationDate, INTERVAL 16 HOUR)) as minutesToFront,
|
|
stock_aggregates.open as underlyingPrice Float64,
|
|
(strike-underlyingPrice)/underlyingPrice as strikePercentageFromUnderlyingPrice Float64
|
|
FROM (
|
|
SELECT
|
|
symbol,
|
|
expirationDate,
|
|
strike,
|
|
type,
|
|
tsStart,
|
|
open
|
|
FROM option_aggregates
|
|
WHERE toDate(tsStart) = expirationDate
|
|
) as option_aggregates
|
|
INNER JOIN stock_aggregates
|
|
ON option_aggregates.symbol = stock_aggregates.symbol
|
|
AND option_aggregates.tsStart = stock_aggregates.tsStart
|
|
|
|
CREATE TABLE option_histories
|
|
(
|
|
symbol LowCardinality(String),
|
|
expirationDate Date,
|
|
strike Float64,
|
|
|
|
tsStart DateTime32,
|
|
open Float64,
|
|
daysToFront UInt16,
|
|
underlyingPrice Float64,
|
|
strikePercentageFromUnderlyingPrice Float64
|
|
)
|
|
ENGINE MergeTree()
|
|
ORDER BY (symbol, daysToFront, strikePercentageFromUnderlyingPrice)
|
|
|
|
|
|
CREATE TABLE calendar_histories
|
|
(
|
|
symbol LowCardinality(String),
|
|
tsStart DateTime32,
|
|
frontExpirationDate Date,
|
|
backExpirationDate Date,
|
|
daysToFrontExpiration UInt16,
|
|
daysBetweenFrontAndBackExpiration UInt16,
|
|
strike Float64,
|
|
underlyingPrice Float64,
|
|
strikePercentageFromUnderlyingPrice Float64,
|
|
calendarPrice Float64
|
|
)
|
|
ENGINE MergeTree()
|
|
PRIMARY KEY (symbol, daysToFrontExpiration, daysBetweenFrontAndBackExpiration, strikePercentageFromUnderlyingPrice)
|
|
ORDER BY (symbol, daysToFrontExpiration, daysBetweenFrontAndBackExpiration, strikePercentageFromUnderlyingPrice, tsStart)
|
|
|
|
|
|
-- INSERT INTO calendar_histories
|
|
-- SELECT
|
|
-- front_option.symbol as symbol,
|
|
-- front_option.tsStart as tsStart,
|
|
-- front_option.expirationDate as frontExpirationDate,
|
|
-- back_option.expirationDate as backExpirationDate,
|
|
-- front_option.daysToFront as daysToFrontExpiration,
|
|
-- backExpirationDate - frontExpirationDate as daysBetweenFrontAndBackExpiration,
|
|
-- front_option.strike as strike,
|
|
-- front_option.underlyingPrice as underlyingPrice,
|
|
-- front_option.strikePercentageFromUnderlyingPrice,
|
|
-- back_option.open - front_option.open as calendarPrice
|
|
-- FROM (
|
|
-- SELECT
|
|
-- symbol,
|
|
-- tsStart,
|
|
-- expirationDate,
|
|
-- strike,
|
|
-- open,
|
|
-- daysToFront,
|
|
-- underlyingPrice,
|
|
-- strikePercentageFromUnderlyingPrice
|
|
-- FROM option_histories
|
|
-- ) AS front_option
|
|
-- LEFT JOIN option_aggregates as back_option
|
|
-- ON front_option.symbol = back_option.symbol
|
|
-- AND front_option.strike = back_option.strike
|
|
-- AND front_option.tsStart = back_option.tsStart
|
|
-- WHERE back_option.expirationDate > front_option.expirationDate
|
|
-- SETTINGS join_algorithm = 'grace_hash', grace_hash_join_initial_buckets = 16, max_bytes_in_join = 536870912
|