DROP TABLE IF EXISTS FT_Refund; DROP TABLE IF EXISTS FT_Registration; DROP TABLE IF EXISTS dim_factories; CREATE TABLE dim_factories ( factory_sk INTEGER identity(1,1) PRIMARY KEY, factory_bk NVARCHAR(100) NOT NULL, factory_name NVARCHAR(250), factory_country NVARCHAR(250) ); GO DROP TABLE IF EXISTS dim_time; CREATE TABLE dim_time ( time_sk INTEGER identity(1,1) PRIMARY KEY, time_bk DATE NOT NULL, time_string NCHAR(10) NOT NULL, year INTEGER, month INTEGER, day INTEGER, quarter INTEGER ); GO DROP PROCEDURE IF EXISTS [dbo].[sPopulateDimDates_v2] GO CREATE PROCEDURE [dbo].[sPopulateDimDates_v2] @FromDate DATE = '1950-01-01', @ToDate DATE = '2050-12-31' AS BEGIN DECLARE @DimDates TABLE ( time_sk INTEGER identity(1,1) PRIMARY KEY, time_bk DATE NOT NULL, time_string NCHAR(10) NOT NULL, year INTEGER, month INTEGER, day INTEGER, quarter INTEGER ); --Setting language SET LANGUAGE English --Populating Dimension WHILE @FromDate <= @ToDate BEGIN INSERT INTO @DimDates( time_bk, time_string, year, month, day, quarter ) SELECT @FromDate as time_bk, convert(nvarchar(10), @FromDate,20) AS time_string, YEAR(@FromDate) AS [year], MONTH(@FromDate) AS [month], DAY(@FromDate) AS [day], DATENAME(QUARTER,@FromDate) AS [quarter] SET @FromDate = DATEADD(DAY, 1, @FromDate) END INSERT INTO dbo.dim_time( time_bk, time_string, year, month, day, quarter ) SELECT time_bk, time_string, year, month, day,quarter FROM @DimDates END GO EXEC [dbo].[sPopulateDimDates_v2] GO DROP TABLE IF EXISTS dim_drugs; CREATE TABLE dim_drugs ( drug_sk INTEGER identity(1, 1) PRIMARY KEY, drug_product_id_bk NVARCHAR(13) NOT NULL, -- business key record_status CHAR(1), -- A for active, D for deactivated drug_product_name NVARCHAR(250), ro_number NVARCHAR(20), drug_product_family_id INTEGER, drug_product_family_name NVARCHAR(250) ); GO DROP TABLE IF EXISTS dim_countries; CREATE TABLE dim_countries ( country_sk INTEGER identity(1, 1) PRIMARY KEY, country_code NVARCHAR(2), -- business key country_name NVARCHAR(250) ); DROP TABLE IF EXISTS dim_claim_statuses; CREATE TABLE dim_claim_statuses ( claim_status_sk INTEGER identity(1, 1) PRIMARY KEY, status_code_bk NVARCHAR(1) NOT NULL, -- A for Accepted, D for Declined, W for Waiting status_description NVARCHAR(50) ); GO -- insert statuses INSERT INTO dim_claim_statuses(status_code_bk, status_description) VALUES ('A', 'Accepted'), ('D', 'Declined'), ('W', 'Waiting'); GO DROP TABLE IF EXISTS claim_status_mapping; CREATE TABLE claim_status_mapping ( status_code_bk NVARCHAR(1), status_code_value NVARCHAR(50) ); GO DROP TABLE IF EXISTS dim_indications; CREATE TABLE dim_indications ( indication_sk INTEGER identity(1, 1) PRIMARY KEY, indication_id_bk nvarchar(13) NOT NULL, record_status CHAR(1), indication_description NVARCHAR(500) ); GO --TABELE FAKTÓW --to by było do SQL Server'a < 2016 --IF OBJECT_ID('dbo.FT1_Registartion') IS NOT NULL DROP TABLE dbo.MyCategories; CREATE TABLE FT_Registration ( ft_registration_sk INTEGER identity(1,1) PRIMARY KEY, expected_response_time_fk integer FOREIGN KEY REFERENCES dim_time(time_sk) NOT NULL, submission_date_fk integer FOREIGN KEY REFERENCES dim_time(time_sk) NOT NULL, response_time_fk integer FOREIGN KEY REFERENCES dim_time(time_sk), -- moze byc null drug_fk integer FOREIGN KEY REFERENCES dim_drugs(drug_sk) NOT NULL, factory_API_fk integer FOREIGN KEY REFERENCES dim_factories(factory_sk) NOT NULL, factory_bulk_fk integer FOREIGN KEY REFERENCES dim_factories(factory_sk) NOT NULL, factory_package_fk integer FOREIGN KEY REFERENCES dim_factories(factory_sk) NOT NULL, country_fk integer FOREIGN KEY REFERENCES dim_countries(country_sk) NOT NULL, --claim status do uspójnienia z tabelą dim_status, wydaje mi się, że można by dodać przedrostek claim do kolumn, będzie czytelniej :) claim_status_fk integer FOREIGN KEY REFERENCES dim_claim_statuses(claim_status_sk) NOT NULL, indication_fk integer FOREIGN KEY REFERENCES dim_indications(indication_sk) NOT NULL, claim_number VARCHAR(20), -- cnt jest tylko zliczeniowy, będzie miał 1, więc dałbym tinyint cnt tinyint, ); GO CREATE TABLE FT_Refund ( ft_registartion_sk INTEGER identity(1,1) PRIMARY KEY, claim_status_fk integer FOREIGN KEY REFERENCES dim_claim_statuses(claim_status_sk) NOT NULL, drug_fk integer FOREIGN KEY REFERENCES dim_drugs(drug_sk) NOT NULL, submission_date_fk integer FOREIGN KEY REFERENCES dim_time(time_sk) NOT NULL, expected_response_fk integer FOREIGN KEY REFERENCES dim_time(time_sk) NOT NULL, response_time_fk integer FOREIGN KEY REFERENCES dim_time(time_sk), -- moze byc null country_fk integer FOREIGN KEY REFERENCES dim_countries(country_sk) NOT NULL, indication_fk integer FOREIGN KEY REFERENCES dim_indications(indication_sk) NOT NULL, --decimal zjada mniej, niż money, do przedyskutowania (precyzja - liczba miejsc przed i po przecinku, skala - liczba miejsc po przecinku) price money, reimbursement_amountPercent smallint, --tu obliczymy jako iloczyn price * reimbursement_amountPercent reimbursement_amount decimal(9,2), claim_number VARCHAR(20), cnt tinyint, ); GO