feat: based on the sec doc match the sql schema

This commit is contained in:
Leonard Excoffier
2024-08-31 16:02:39 -04:00
parent 00a59b27ce
commit 57b13dbec5

View File

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