feat: based on the sec doc match the sql schema
This commit is contained in:
140
db_schema.sql
140
db_schema.sql
@@ -1,87 +1,89 @@
|
||||
-- @block
|
||||
-- Create tables
|
||||
-- Create 'sub' table
|
||||
-- Create SUB table
|
||||
CREATE TABLE sub (
|
||||
adsh VARCHAR(255) PRIMARY KEY,
|
||||
cik BIGINT,
|
||||
name VARCHAR(255),
|
||||
sic DOUBLE PRECISION,
|
||||
countryba VARCHAR(100),
|
||||
stprba VARCHAR(100),
|
||||
cityba VARCHAR(255),
|
||||
zipba VARCHAR(50),
|
||||
bas1 VARCHAR(255),
|
||||
bas2 VARCHAR(255),
|
||||
baph VARCHAR(255),
|
||||
countryma VARCHAR(100),
|
||||
stprma VARCHAR(100),
|
||||
cityma VARCHAR(255),
|
||||
zipma VARCHAR(50),
|
||||
mas1 VARCHAR(255),
|
||||
mas2 VARCHAR(255),
|
||||
countryinc VARCHAR(100),
|
||||
stprinc VARCHAR(100),
|
||||
ein BIGINT,
|
||||
former VARCHAR(255),
|
||||
changed DOUBLE PRECISION,
|
||||
afs VARCHAR(255),
|
||||
wksi BIGINT,
|
||||
fye DOUBLE PRECISION,
|
||||
form VARCHAR(50),
|
||||
period DOUBLE PRECISION,
|
||||
fy DOUBLE PRECISION,
|
||||
fp VARCHAR(50),
|
||||
filed BIGINT,
|
||||
accepted VARCHAR(255),
|
||||
prevrpt BIGINT,
|
||||
detail BIGINT,
|
||||
instance VARCHAR(255),
|
||||
nciks BIGINT,
|
||||
aciks VARCHAR(255)
|
||||
adsh CHAR(20) PRIMARY KEY NOT NULL, -- Accession number, primary key
|
||||
cik BIGINT NOT NULL, -- Central Index Key (CIK)
|
||||
name VARCHAR(150) NOT NULL, -- Name of registrant
|
||||
sic INTEGER, -- Standard Industrial Classification (SIC)
|
||||
countryba CHAR(2) NOT NULL, -- Country of business address (ISO 3166-1)
|
||||
stprba CHAR(2), -- State/Province of business address (if applicable)
|
||||
cityba VARCHAR(30) NOT NULL, -- 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(12), -- 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) NOT NULL, -- 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 NOT NULL, -- Well Known Seasoned Issuer (WKSI)
|
||||
fye CHAR(4) NOT NULL, -- Fiscal Year End Date (format: mmdd)
|
||||
form VARCHAR(10) NOT NULL, -- Submission type (Form)
|
||||
period CHAR(8) NOT NULL, -- Balance Sheet Date (format: yyyymmdd)
|
||||
fy INTEGER NOT NULL, -- Fiscal Year focus (Year)
|
||||
fp CHAR(2) NOT NULL, -- Fiscal Period focus (e.g., FY, Q1)
|
||||
filed CHAR(8) NOT NULL, -- Date of filing (format: yyyymmdd)
|
||||
accepted TIMESTAMP NOT NULL, -- Acceptance date and time by SEC
|
||||
prevrpt BOOLEAN NOT NULL, -- Indicates if the submission was amended
|
||||
detail BOOLEAN NOT NULL, -- Indicates detail in footnotes and schedules
|
||||
instance VARCHAR(32) NOT NULL, -- Name of submitted XBRL Instance Document
|
||||
nciks INTEGER NOT NULL, -- Number of CIKs included in submission
|
||||
aciks VARCHAR(120) -- Additional CIKs included in submission
|
||||
);
|
||||
|
||||
-- Create 'tag' table
|
||||
-- Create TAG table
|
||||
CREATE TABLE tag (
|
||||
tag VARCHAR(255),
|
||||
version VARCHAR(255),
|
||||
custom BIGINT,
|
||||
abstract BIGINT,
|
||||
datatype VARCHAR(255),
|
||||
iord VARCHAR(50),
|
||||
crdr VARCHAR(50),
|
||||
tlabel VARCHAR(255),
|
||||
doc TEXT,
|
||||
tag VARCHAR(256) NOT NULL, -- Unique identifier for a tag
|
||||
version CHAR(20) NOT NULL, -- Taxonomy version if standard, else adsh
|
||||
custom BOOLEAN NOT NULL, -- 1 if custom tag, 0 if standard tag
|
||||
abstract BOOLEAN NOT NULL, -- 1 if abstract (not numeric), 0 if numeric
|
||||
datatype VARCHAR(20), -- Data type (if numeric)
|
||||
iord CHAR(1) NOT NULL, -- "I" for point-in-time, "D" for duration
|
||||
crdr CHAR(1), -- Credit/ Debit nature, if monetary
|
||||
tlabel VARCHAR(512), -- Label text
|
||||
doc VARCHAR(2048), -- Tag definition/documentation
|
||||
|
||||
PRIMARY KEY (tag, version)
|
||||
);
|
||||
|
||||
-- Create 'num' table
|
||||
-- Create NUM table
|
||||
CREATE TABLE num (
|
||||
adsh VARCHAR(255),
|
||||
tag VARCHAR(255),
|
||||
version VARCHAR(255),
|
||||
coreg VARCHAR(255),
|
||||
ddate BIGINT,
|
||||
qtrs BIGINT,
|
||||
uom VARCHAR(50),
|
||||
value DOUBLE PRECISION,
|
||||
footnote TEXT,
|
||||
PRIMARY KEY (adsh, tag, version, ddate),
|
||||
adsh CHAR(20) NOT NULL, -- Accession number
|
||||
tag VARCHAR(256) NOT NULL, -- Tag name
|
||||
version CHAR(20) NOT NULL, -- Taxonomy version
|
||||
coreg VARCHAR(256), -- 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, ddate, qtrs, uom, coreg),
|
||||
FOREIGN KEY (adsh) REFERENCES sub(adsh),
|
||||
FOREIGN KEY (tag, version) REFERENCES tag(tag, version)
|
||||
);
|
||||
|
||||
-- Create 'pre' table
|
||||
-- Create PRE table
|
||||
CREATE TABLE pre (
|
||||
adsh VARCHAR(255),
|
||||
report BIGINT,
|
||||
line BIGINT,
|
||||
stmt VARCHAR(255),
|
||||
inpth BIGINT,
|
||||
rfile VARCHAR(255),
|
||||
tag VARCHAR(255),
|
||||
version VARCHAR(255),
|
||||
plabel VARCHAR(255),
|
||||
negating BIGINT,
|
||||
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) NOT NULL, -- Statement type (BS, IS, CF, EQ, CI, etc.)
|
||||
inpth BOOLEAN NOT NULL, -- Presented parenthetically or not
|
||||
rfile CHAR(1) NOT NULL, -- File type ("H" or "X")
|
||||
tag VARCHAR(256) NOT NULL, -- Tag name
|
||||
version CHAR(20) NOT NULL, -- Taxonomy version
|
||||
plabel VARCHAR(512) NOT NULL, -- Preferred label for presentation
|
||||
|
||||
PRIMARY KEY (adsh, report, line),
|
||||
FOREIGN KEY (adsh) REFERENCES sub(adsh),
|
||||
FOREIGN KEY (tag, version) REFERENCES tag(tag, version)
|
||||
|
||||
Reference in New Issue
Block a user