Files
stockdb/db_schema.sql
2024-08-31 18:26:54 -04:00

111 lines
5.9 KiB
SQL

-- @block
-- Create tables
-- Create SUB table
CREATE TABLE sub (
adsh CHAR(20) PRIMARY KEY NOT NULL, -- Accession number, primary key
cik BIGINT , -- Central Index Key (CIK)
name VARCHAR(150) , -- Name of registrant
sic INTEGER, -- Standard Industrial Classification (SIC)
countryba CHAR(2) , -- Country of business address (ISO 3166-1)
stprba CHAR(2), -- State/Province of business address (if applicable)
cityba VARCHAR(30) , -- City of business address
zipba VARCHAR(10), -- Zip code of business address
bas1 VARCHAR(40), -- First line of business address
bas2 VARCHAR(40), -- Second line of business address
baph VARCHAR(20), -- Phone number of business address
countryma CHAR(2), -- Country of mailing address (ISO 3166-1)
stprma CHAR(2), -- State/Province of mailing address (if applicable)
cityma VARCHAR(30), -- City of mailing address
zipma VARCHAR(10), -- Zip code of mailing address
mas1 VARCHAR(40), -- First line of mailing address
mas2 VARCHAR(40), -- Second line of mailing address
countryinc CHAR(3), -- Country of incorporation
stprinc CHAR(2), -- State/Province of incorporation (if applicable)
ein CHAR(10), -- Employer Identification Number
former VARCHAR(150), -- Most recent former name
changed CHAR(8), -- Date of change from former name
afs CHAR(5), -- Filer Status with SEC
wksi BOOLEAN , -- Well Known Seasoned Issuer (WKSI)
fye CHAR(4) , -- Fiscal Year End Date (format: mmdd)
form VARCHAR(10) , -- Submission type (Form)
period CHAR(8) , -- Balance Sheet Date (format: yyyymmdd)
fy INTEGER , -- Fiscal Year focus (Year)
fp CHAR(2) , -- Fiscal Period focus (e.g., FY, Q1)
filed CHAR(8) , -- Date of filing (format: yyyymmdd)
accepted TIMESTAMP , -- Acceptance date and time by SEC
prevrpt BOOLEAN , -- Indicates if the submission was amended
detail BOOLEAN , -- Indicates detail in footnotes and schedules
instance VARCHAR(32) , -- Name of submitted XBRL Instance Document
nciks INTEGER , -- Number of CIKs included in submission
aciks VARCHAR(120) -- Additional CIKs included in submission
);
-- Create TAG table
CREATE TABLE tag (
tag VARCHAR(256) NOT NULL, -- Unique identifier for a tag
version CHAR(20) NOT NULL, -- Taxonomy version if standard, else adsh
custom BOOLEAN , -- 1 if custom tag, 0 if standard tag
abstract BOOLEAN , -- 1 if abstract (not numeric), 0 if numeric
datatype VARCHAR(20), -- Data type (if numeric)
iord CHAR(1), -- "I" for point-in-time, "D" for duration
crdr CHAR(1), -- Credit/ Debit nature, if monetary
tlabel VARCHAR(512), -- Label text
doc TEXT, -- Tag definition/documentation
PRIMARY KEY (tag, version)
);
-- Create NUM table
CREATE TABLE num (
adsh CHAR(20) NOT NULL, -- Accession number
tag VARCHAR(256) NOT NULL, -- Tag name
version CHAR(20) NOT NULL, -- Taxonomy version
coreg VARCHAR(256) NOT NULL, -- Coregistrant ID
ddate CHAR(8) NOT NULL, -- Period end date (format: yyyymmdd)
qtrs INTEGER NOT NULL, -- Number of quarters (0 for point-in-time values)
uom VARCHAR(20) NOT NULL, -- Unit of Measure
value NUMERIC(28,4), -- Value (up to 4 decimal places)
footnote VARCHAR(512), -- Footnote (superscripted text)
PRIMARY KEY (adsh, tag, version, coreg, ddate, qtrs, uom),
FOREIGN KEY (adsh) REFERENCES sub(adsh),
FOREIGN KEY (tag, version) REFERENCES tag(tag, version)
);
-- Create PRE table
CREATE TABLE pre (
adsh CHAR(20) NOT NULL, -- Accession number
report INTEGER NOT NULL, -- Sequence number of report
line INTEGER NOT NULL, -- Sequence number of line in the report
stmt CHAR(2) , -- Statement type (BS, IS, CF, EQ, CI, etc.)
inpth BOOLEAN , -- Presented parenthetically or not
rfile CHAR(1) , -- File type ("H" or "X")
tag VARCHAR(256) NOT NULL, -- Tag name
version CHAR(20) NOT NULL, -- Taxonomy version
plabel VARCHAR(512) , -- Preferred label for presentation
PRIMARY KEY (adsh, report, line),
FOREIGN KEY (adsh) REFERENCES sub(adsh),
FOREIGN KEY (tag, version) REFERENCES tag(tag, version)
);
-- @end
-- @block
-- Reset db
SET FOREIGN_KEY_CHECKS = 0;
DROP TABLE IF EXISTS num;
DROP TABLE IF EXISTS pre;
DROP TABLE IF EXISTS sub;
DROP TABLE IF EXISTS tag;
SET FOREIGN_KEY_CHECKS = 1;
-- @end\
-- baph is 12 in new 20 in old
-- doc is 2048 in new unlimitted in old
-- countrinc was set as cant be null, but there are some null values
-- iord was set as cant be null, but there are some null values
-- there is a duplicated primary key in 2009q3tagline5014
-- there is a duplicated primary key in 2009q3tagline9980 its not the same case but same string so causes problem