forked from s485936/PRAPRO2
feat: added sql scripts that i used for this database, but everything should work remotely as the database is in cloud
This commit is contained in:
parent
2f7dbbc788
commit
f8327251ef
126
src/sql/create-schema.sql
Normal file
126
src/sql/create-schema.sql
Normal file
@ -0,0 +1,126 @@
|
||||
CREATE SCHEMA people_scoreboard;
|
||||
|
||||
CREATE TABLE people_scoreboard.people
|
||||
(
|
||||
id SERIAL PRIMARY KEY,
|
||||
parent1Id INT REFERENCES people_scoreboard.people (id),
|
||||
parent2Id INT REFERENCES people_scoreboard.people (id),
|
||||
birth_timestamp TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
CREATE TABLE people_scoreboard.activities
|
||||
(
|
||||
id SERIAL PRIMARY KEY,
|
||||
name VARCHAR(255),
|
||||
value INT
|
||||
);
|
||||
|
||||
CREATE TABLE people_scoreboard.activity_log
|
||||
(
|
||||
id SERIAL PRIMARY KEY,
|
||||
activity_id INT REFERENCES people_scoreboard.activities (id),
|
||||
human_id INT REFERENCES people_scoreboard.people (id),
|
||||
start_timestamp TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
end_timestamp TIMESTAMPTZ
|
||||
);
|
||||
|
||||
CREATE TABLE people_scoreboard.occupations
|
||||
(
|
||||
id SERIAL PRIMARY KEY,
|
||||
name VARCHAR(255),
|
||||
value INT
|
||||
);
|
||||
|
||||
CREATE TABLE people_scoreboard.occupation_log
|
||||
(
|
||||
id SERIAL PRIMARY KEY,
|
||||
occupation_id INT REFERENCES people_scoreboard.occupations (id),
|
||||
human_id INT REFERENCES people_scoreboard.people (id),
|
||||
start_timestamp TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
|
||||
end_timestamp TIMESTAMPTZ,
|
||||
grade INT
|
||||
);
|
||||
|
||||
CREATE OR REPLACE FUNCTION people_scoreboard.get_activity_value(_humanId INT)
|
||||
RETURNS INT AS
|
||||
$$
|
||||
DECLARE
|
||||
_totalValue INT;
|
||||
BEGIN
|
||||
SELECT SUM(value)
|
||||
INTO _totalValue
|
||||
FROM people_scoreboard.activity_log
|
||||
JOIN people_scoreboard.activities
|
||||
ON people_scoreboard.activity_log.activity_id = people_scoreboard.activities.id
|
||||
WHERE people_scoreboard.activity_log.human_id = _humanId;
|
||||
|
||||
RETURN _totalValue;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION people_scoreboard.get_occupation_value(_humanId INT)
|
||||
RETURNS INT AS
|
||||
$$
|
||||
DECLARE
|
||||
_totalValue INT;
|
||||
BEGIN
|
||||
SELECT SUM(value * grade * EXTRACT(YEAR FROM AGE(COALESCE(end_timestamp, CURRENT_TIMESTAMP), start_timestamp)))
|
||||
INTO _totalValue
|
||||
FROM people_scoreboard.occupation_log
|
||||
JOIN people_scoreboard.occupations
|
||||
ON people_scoreboard.occupation_log.occupation_id = people_scoreboard.occupations.id
|
||||
WHERE people_scoreboard.occupation_log.human_id = _humanId;
|
||||
|
||||
RETURN _totalValue;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION people_scoreboard.get_human_value(_humanId INT)
|
||||
RETURNS INT AS
|
||||
$$
|
||||
DECLARE
|
||||
_activityValue INT;
|
||||
_occupationValue INT;
|
||||
BEGIN
|
||||
_activityValue := people_scoreboard.get_activity_value(_humanId);
|
||||
_occupationValue := people_scoreboard.get_occupation_value(_humanId);
|
||||
|
||||
RETURN _activityValue + _occupationValue;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION people_scoreboard.get_all_people_values(_offset INT, _limit INT)
|
||||
RETURNS TABLE
|
||||
(
|
||||
humanId INT,
|
||||
value INT
|
||||
)
|
||||
AS
|
||||
$$
|
||||
BEGIN
|
||||
RETURN QUERY
|
||||
SELECT id, people_scoreboard.get_human_value(id)
|
||||
FROM people_scoreboard.people
|
||||
ORDER BY id
|
||||
LIMIT _limit OFFSET _offset;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE VIEW people_scoreboard.human_logs AS
|
||||
SELECT p.id AS humanId,
|
||||
json_agg(json_build_object('name', a.name, 'value', a.value, 'start_timestamp',
|
||||
al.start_timestamp, 'end_timestamp',
|
||||
al.end_timestamp)) AS activity_log,
|
||||
json_agg(json_build_object('name', o.name, 'value', o.value, 'start_timestamp',
|
||||
ol.start_timestamp, 'end_timestamp',
|
||||
ol.end_timestamp, 'grade', ol.grade)) AS occupation_log
|
||||
FROM people_scoreboard.people p
|
||||
LEFT JOIN people_scoreboard.activity_log al ON p.id = al.human_id
|
||||
LEFT JOIN people_scoreboard.occupation_log ol ON p.id = ol.human_id
|
||||
LEFT JOIN people_scoreboard.activities a ON al.activity_id = a.id
|
||||
LEFT JOIN people_scoreboard.occupations o ON ol.occupation_id = o.id
|
||||
GROUP BY p.id;
|
||||
|
||||
|
||||
|
||||
|
1
src/sql/drop-schema.sql
Normal file
1
src/sql/drop-schema.sql
Normal file
@ -0,0 +1 @@
|
||||
drop schema if exists people_scoreboard cascade;
|
90
src/sql/insert_test_data.sql
Normal file
90
src/sql/insert_test_data.sql
Normal file
@ -0,0 +1,90 @@
|
||||
TRUNCATE TABLE people_scoreboard.activity_log;
|
||||
TRUNCATE TABLE people_scoreboard.occupation_log;
|
||||
TRUNCATE TABLE people_scoreboard.people cascade;
|
||||
TRUNCATE TABLE people_scoreboard.activities cascade;
|
||||
TRUNCATE TABLE people_scoreboard.occupations cascade;
|
||||
|
||||
SELECT setval(pg_get_serial_sequence('people_scoreboard.people', 'id'), coalesce(max(id),0) + 1, false) FROM people_scoreboard.people;
|
||||
SELECT setval(pg_get_serial_sequence('people_scoreboard.activities', 'id'), coalesce(max(id),0) + 1, false) FROM people_scoreboard.activities;
|
||||
SELECT setval(pg_get_serial_sequence('people_scoreboard.occupations', 'id'), coalesce(max(id),0) + 1, false) FROM people_scoreboard.occupations;
|
||||
SELECT setval(pg_get_serial_sequence('people_scoreboard.activity_log', 'id'), coalesce(max(id),0) + 1, false) FROM people_scoreboard.activity_log;
|
||||
SELECT setval(pg_get_serial_sequence('people_scoreboard.occupation_log', 'id'), coalesce(max(id),0) + 1, false) FROM people_scoreboard.occupation_log;
|
||||
|
||||
INSERT INTO people_scoreboard.activities (name, value)
|
||||
VALUES ('Exercising', 5),
|
||||
('Working', 20),
|
||||
('Sleeping', 0),
|
||||
('Eating', 0),
|
||||
('Studying', 15),
|
||||
('Procrastinating', -30),
|
||||
('Praising Government', 50),
|
||||
('Talking about other nations positively', -80),
|
||||
('Conspiring', -500),
|
||||
('Talking about other nations negatively', 100);
|
||||
INSERT INTO people_scoreboard.occupations (name, value)
|
||||
VALUES ('Student', 100),
|
||||
('Engineer', 200),
|
||||
('Doctor', 300),
|
||||
('Lawyer', 400),
|
||||
('Teacher', 500),
|
||||
('Unemployed', -100),
|
||||
('Parent', 500);
|
||||
|
||||
INSERT INTO people_scoreboard.people (parent1Id, parent2Id, birth_timestamp)
|
||||
VALUES (NULL, NULL, '1980-01-01 00:00:00');
|
||||
INSERT INTO people_scoreboard.people (parent1Id, parent2Id, birth_timestamp)
|
||||
VALUES (NULL, NULL, '1980-01-01 00:00:00');
|
||||
|
||||
INSERT INTO people_scoreboard.people (parent1Id, parent2Id, birth_timestamp)
|
||||
VALUES (1, 2, '2000-01-01 00:00:00');
|
||||
INSERT INTO people_scoreboard.people (parent1Id, parent2Id, birth_timestamp)
|
||||
VALUES (1, 2, '2002-01-01 00:00:00');
|
||||
INSERT INTO people_scoreboard.people (parent1Id, parent2Id, birth_timestamp)
|
||||
VALUES (1, 2, '2004-01-01 00:00:00');
|
||||
|
||||
INSERT INTO people_scoreboard.people (parent1Id, parent2Id, birth_timestamp)
|
||||
VALUES (NULL, NULL, '2001-01-01 00:00:00');
|
||||
|
||||
INSERT INTO people_scoreboard.people (parent1Id, parent2Id)
|
||||
VALUES (2, 5);
|
||||
INSERT INTO people_scoreboard.people (parent1Id, parent2Id)
|
||||
VALUES (2, 5);
|
||||
|
||||
DO
|
||||
$do$
|
||||
DECLARE
|
||||
random_activity_id INT;
|
||||
random_occupation_id INT;
|
||||
random_person_id INT;
|
||||
random_start_timestamp TIMESTAMP;
|
||||
random_end_timestamp TIMESTAMP;
|
||||
BEGIN
|
||||
FOR i IN 1..20
|
||||
LOOP -- Insert 100 random rows
|
||||
-- Get random activity, occupation, and person IDs
|
||||
SELECT floor(random() * 10 + 1)::INT INTO random_activity_id; -- 10 activities
|
||||
SELECT floor(random() * 7 + 1)::INT INTO random_occupation_id; -- 7 occupations
|
||||
SELECT floor(random() * 6 + 1)::INT INTO random_person_id;
|
||||
-- 6 people
|
||||
|
||||
-- Get random start and end timestamps within the last year
|
||||
SELECT NOW() - (random() * interval '365 days') INTO random_start_timestamp;
|
||||
SELECT random_start_timestamp + (random() * interval '24 hours') INTO random_end_timestamp;
|
||||
|
||||
-- Insert into activity_log
|
||||
INSERT INTO people_scoreboard.activity_log (activity_id, human_id, start_timestamp, end_timestamp)
|
||||
VALUES (random_activity_id, random_person_id, random_start_timestamp, random_end_timestamp);
|
||||
|
||||
IF i % 2 = 0 THEN
|
||||
-- Insert into occupation_log
|
||||
INSERT INTO people_scoreboard.occupation_log (occupation_id, human_id, start_timestamp, end_timestamp, grade)
|
||||
VALUES (random_occupation_id, random_person_id, random_start_timestamp, random_end_timestamp,
|
||||
floor(random() * 5 + 1)::INT); -- Random grade between 1 and 5
|
||||
END IF;
|
||||
END LOOP;
|
||||
END
|
||||
$do$;
|
||||
|
||||
|
||||
|
||||
|
Loading…
Reference in New Issue
Block a user