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.
93 lines
2.3 KiB
SQL
93 lines
2.3 KiB
SQL
-- list around-the-money calls:
|
|
SELECT
|
|
s.symbol,
|
|
s.close,
|
|
o.strike,
|
|
o.delta,
|
|
o.bid,
|
|
o.ask
|
|
FROM
|
|
stock_quote AS s
|
|
INNER JOIN
|
|
option_quote AS o
|
|
ON o.underlying = s.symbol
|
|
WHERE
|
|
abs(o.strike-s.close)/s.close < 0.07
|
|
AND
|
|
o.type = 'call'
|
|
LIMIT 30;
|
|
|
|
-- historical payoff of at-the-money calendars:
|
|
SELECT
|
|
s.quote_date,
|
|
s.symbol,
|
|
s.close,
|
|
front_month.strike AS strike,
|
|
front_month.type AS "type",
|
|
front_month.expiration AS front_month_exp,
|
|
back_month.expiration AS back_month_exp,
|
|
(back_month.ask-front_month.bid) AS cost,
|
|
(back_month_at_exp.bid-cost) AS payout
|
|
FROM
|
|
stock_quote AS s
|
|
INNER JOIN
|
|
option_quote AS front_month
|
|
ON
|
|
front_month.underlying = s.symbol
|
|
AND
|
|
front_month.quote_date = s.quote_date
|
|
AND
|
|
front_month.expiration > s.quote_date
|
|
INNER JOIN
|
|
option_quote AS back_month
|
|
ON
|
|
back_month.underlying = s.symbol
|
|
AND
|
|
back_month.quote_date = front_month.quote_date
|
|
AND
|
|
back_month.strike = front_month.strike
|
|
AND
|
|
back_month.type = front_month.type
|
|
AND
|
|
back_month.expiration > front_month.expiration
|
|
INNER JOIN
|
|
option_quote AS back_month_at_exp
|
|
ON
|
|
back_month_at_exp.underlying = s.symbol
|
|
AND
|
|
back_month_at_exp.strike = back_month.strike
|
|
AND
|
|
back_month_at_exp.type = back_month.type
|
|
AND
|
|
back_month_at_exp.expiration = back_month.expiration
|
|
AND
|
|
back_month_at_exp.quote_date = front_month.expiration
|
|
WHERE
|
|
s.symbol = 'MSFT'
|
|
ORDER BY
|
|
s.quote_date,
|
|
s.symbol,
|
|
strike,
|
|
"type"
|
|
LIMIT 30;
|
|
|
|
-- given an underlying, contract type, strike, and front/back expirations: for each quote_date, list prices of calendars:
|
|
SELECT
|
|
"front_contract"."quote_date",
|
|
("back_contract"."ask" - "front_contract"."bid") AS "price"
|
|
FROM
|
|
"option_quote" AS "front_contract"
|
|
INNER JOIN
|
|
"option_quote" AS "back_contract"
|
|
ON
|
|
"back_contract"."underlying" = "front_contract"."underlying"
|
|
AND "back_contract"."type" = "front_contract"."type"
|
|
AND "back_contract"."quote_date" = "front_contract"."quote_date"
|
|
AND "back_contract"."strike" = "front_contract"."strike"
|
|
AND "back_contract"."expiration" = '?'
|
|
WHERE
|
|
"front_contract"."underlying" = '?'
|
|
AND "front_contract"."type" = 'call'
|
|
AND "front_contract"."strike" = '?'
|
|
AND "front_contract"."expiration" = '?'
|