diff --git a/sql/data_warehouse/DATE_FUNC.sql b/sql/data_warehouse/DATE_FUNC.sql new file mode 100644 index 0000000..8788393 --- /dev/null +++ b/sql/data_warehouse/DATE_FUNC.sql @@ -0,0 +1,7 @@ +CREATE OR REPLACE FUNCTION get_date_primary_key(ts timestamp) RETURNS integer AS $$ + BEGIN + RETURN 10000 * EXTRACT(YEAR FROM ts) + + 100 * EXTRACT(MONTH FROM ts) + + EXTRACT(DAY FROM ts); + END; +$$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/sql/data_warehouse/DIM_DATE.sql b/sql/data_warehouse/DIM_DATE.sql new file mode 100644 index 0000000..86a38eb --- /dev/null +++ b/sql/data_warehouse/DIM_DATE.sql @@ -0,0 +1,22 @@ +-- Table: public."DIM_DATE" + +-- DROP TABLE public."DIM_DATE"; + +CREATE TABLE public."DIM_DATE" +( + "DATE_ID" bigint NOT NULL DEFAULT nextval('"DIM_DATE_DATE_ID_seq"'::regclass), + "YEAR" numeric NOT NULL, + "MONTH" numeric NOT NULL, + "MONTH_NAME" character varying(255) COLLATE pg_catalog."default" NOT NULL, + "WEEK" numeric NOT NULL, + "DAY" numeric NOT NULL, + "DAY_NAME" character varying(255) COLLATE pg_catalog."default" NOT NULL, + CONSTRAINT "DIM_DATE_pkey" PRIMARY KEY ("DATE_ID") +) +WITH ( + OIDS = FALSE +) +TABLESPACE pg_default; + +ALTER TABLE public."DIM_DATE" + OWNER to monnethicadmin; \ No newline at end of file diff --git a/sql/data_warehouse/DIM_USER.sql b/sql/data_warehouse/DIM_USER.sql new file mode 100644 index 0000000..d40a7d8 --- /dev/null +++ b/sql/data_warehouse/DIM_USER.sql @@ -0,0 +1,17 @@ +-- Table: public."DIM_USER" + +-- DROP TABLE public."DIM_USER"; + +CREATE TABLE public."DIM_USER" +( + "USER_ID" bigint NOT NULL DEFAULT nextval('"DIM_USER_USER_ID_seq"'::regclass), + "USER_HASH" character varying(255) COLLATE pg_catalog."default" NOT NULL, + CONSTRAINT "DIM_USER_pkey" PRIMARY KEY ("USER_ID") +) +WITH ( + OIDS = FALSE +) +TABLESPACE pg_default; + +ALTER TABLE public."DIM_USER" + OWNER to monnethicadmin; \ No newline at end of file diff --git a/sql/data_warehouse/DIM_WALLET.sql b/sql/data_warehouse/DIM_WALLET.sql new file mode 100644 index 0000000..7ca4183 --- /dev/null +++ b/sql/data_warehouse/DIM_WALLET.sql @@ -0,0 +1,18 @@ +-- Table: public."DIM_WALLET" + +-- DROP TABLE public."DIM_WALLET"; + +CREATE TABLE public."DIM_WALLET" +( + "WALLET_ID" bigint NOT NULL DEFAULT nextval('"DIM_WALLET_WALLET_ID_seq"'::regclass), + "USER_ID" bigint NOT NULL, + "WALLET_HASH" character varying(255) COLLATE pg_catalog."default" NOT NULL, + CONSTRAINT "DIM_WALLET_pkey" PRIMARY KEY ("WALLET_ID") +) +WITH ( + OIDS = FALSE +) +TABLESPACE pg_default; + +ALTER TABLE public."DIM_WALLET" + OWNER to monnethicadmin; \ No newline at end of file diff --git a/sql/data_warehouse/FACT_SESSION.sql b/sql/data_warehouse/FACT_SESSION.sql new file mode 100644 index 0000000..785f6b5 --- /dev/null +++ b/sql/data_warehouse/FACT_SESSION.sql @@ -0,0 +1,37 @@ +-- Table: public."FACT_SESSION" + +-- DROP TABLE public."FACT_SESSION"; + +CREATE TABLE public."FACT_SESSION" +( + "DATE_ID" bigint NOT NULL, + "USER_ID" bigint NOT NULL, + "START" bigint NOT NULL, + "END" bigint NOT NULL, + "TIME" bigint NOT NULL, + CONSTRAINT "FACT_SESSION_pkey" PRIMARY KEY ("DATE_ID", "USER_ID"), + CONSTRAINT "DATE_ID_FK" FOREIGN KEY ("DATE_ID") + REFERENCES public."DIM_DATE" ("DATE_ID") MATCH SIMPLE + ON UPDATE NO ACTION + ON DELETE NO ACTION, + CONSTRAINT "USER_ID_FK" FOREIGN KEY ("USER_ID") + REFERENCES public."DIM_USER" ("USER_ID") MATCH SIMPLE + ON UPDATE NO ACTION + ON DELETE NO ACTION +) +WITH ( + OIDS = FALSE +) +TABLESPACE pg_default; + +ALTER TABLE public."FACT_SESSION" + OWNER to monnethicadmin; + +-- Index: fki_USER_ID_FK + +-- DROP INDEX public."fki_USER_ID_FK"; + +CREATE INDEX "fki_USER_ID_FK" + ON public."FACT_SESSION" USING btree + ("USER_ID") + TABLESPACE pg_default; \ No newline at end of file diff --git a/sql/data_warehouse/FACT_TRANSACTION.sql b/sql/data_warehouse/FACT_TRANSACTION.sql new file mode 100644 index 0000000..04c3e90 --- /dev/null +++ b/sql/data_warehouse/FACT_TRANSACTION.sql @@ -0,0 +1,27 @@ +-- Table: public."FACT_TRANSACTION" + +-- DROP TABLE public."FACT_TRANSACTION"; + +CREATE TABLE public."FACT_TRANSACTION" +( + "DATE_ID" bigint NOT NULL, + "WALLET_ID" bigint NOT NULL, + "TRANSACTION_ID" numeric NOT NULL, + "AMOUNT" numeric NOT NULL, + CONSTRAINT "FACT_TRANSACTION_pkey" PRIMARY KEY ("DATE_ID", "WALLET_ID"), + CONSTRAINT "DATE_ID" FOREIGN KEY ("DATE_ID") + REFERENCES public."DIM_DATE" ("DATE_ID") MATCH SIMPLE + ON UPDATE NO ACTION + ON DELETE NO ACTION, + CONSTRAINT "WALLET_ID" FOREIGN KEY ("WALLET_ID") + REFERENCES public."DIM_WALLET" ("WALLET_ID") MATCH SIMPLE + ON UPDATE NO ACTION + ON DELETE NO ACTION +) +WITH ( + OIDS = FALSE +) +TABLESPACE pg_default; + +ALTER TABLE public."FACT_TRANSACTION" + OWNER to monnethicadmin; \ No newline at end of file diff --git a/sql/data_warehouse/SCRIPT_DIM_DATE.sql b/sql/data_warehouse/SCRIPT_DIM_DATE.sql new file mode 100644 index 0000000..57b72ca --- /dev/null +++ b/sql/data_warehouse/SCRIPT_DIM_DATE.sql @@ -0,0 +1,42 @@ +WITH date1 AS ( + SELECT generate_series('2018-01-01'::timestamp, '2021-12-31'::timestamp, '1 day') AS ts +), date2 AS ( + SELECT get_date_primary_key(ts) AS DATE_ID, + EXTRACT(YEAR FROM ts) AS N_YEAR, + EXTRACT(MONTH FROM ts) AS N_MONTH, + EXTRACT(WEEK FROM ts) AS N_WEEK, + EXTRACT(DAY FROM ts) AS DAY_MONTH, + EXTRACT(ISODOW FROM ts) AS DAY_WEEK + FROM date1 +), date3 AS ( + SELECT + *, + CASE + WHEN N_MONTH = 1 THEN 'January' + WHEN N_MONTH = 2 THEN 'February' + WHEN N_MONTH = 3 THEN 'March' + WHEN N_MONTH = 4 THEN 'April' + WHEN N_MONTH = 5 THEN 'May' + WHEN N_MONTH = 6 THEN 'June' + WHEN N_MONTH = 7 THEN 'July' + WHEN N_MONTH = 8 THEN 'August' + WHEN N_MONTH = 9 THEN 'September' + WHEN N_MONTH = 10 THEN 'October' + WHEN N_MONTH = 11 THEN 'November' + WHEN N_MONTH = 12 THEN 'December' + END AS MONTH_NAME, + CASE + WHEN DAY_WEEK = 1 THEN 'Monday' + WHEN DAY_WEEK = 2 THEN 'Tuesday' + WHEN DAY_WEEK = 3 THEN 'Wednesday' + WHEN DAY_WEEK = 4 THEN 'Thursday' + WHEN DAY_WEEK = 5 THEN 'Friday' + WHEN DAY_WEEK = 6 THEN 'Saturday' + WHEN DAY_WEEK = 7 THEN 'Sunday' + END AS DAY_NAME + FROM date2 +) + +INSERT INTO public."DIM_DATE" + SELECT DATE_ID,N_YEAR,N_MONTH,MONTH_NAME,N_WEEK,DAY_MONTH,DAY_NAME + FROM date3; \ No newline at end of file