forgot migrations 🤦

pull/5/head
Adam Veldhousen 1 year ago
parent fa8516b26f
commit d1c0369308
Signed by: adam
GPG Key ID: 6DB29003C6DD1E4B

@ -0,0 +1,119 @@
-- +goose Up
START TRANSACTION;
CREATE SCHEMA IF NOT EXISTS catalog;
CREATE TABLE IF NOT EXISTS catalog.upcoming_auctions (
id SERIAL PRIMARY KEY,
fingerprint VARCHAR(128) NOT NULL UNIQUE,
title VARCHAR(1024) NOT NULL,
description TEXT DEFAULT ''::TEXT NOT NULL,
startts TIMESTAMP NOT NULL,
endts TIMESTAMP,
itemcount INTEGER DEFAULT 0 NOT NULL,
sourcesiteurl VARCHAR(1024) DEFAULT ''::CHARACTER VARYING NOT NULL,
sourcesitename VARCHAR(256) NOT NULL,
sourceurl VARCHAR(1024) NOT NULL,
country VARCHAR(64) NOT NULL,
province VARCHAR(128) NOT NULL
);
CREATE TABLE IF NOT EXISTS catalog.upcoming_auctions_fts (
id SERIAL PRIMARY KEY,
auctionid INTEGER REFERENCES CATALOG.UPCOMING_AUCTIONS,
title VARCHAR(1024) NOT NULL,
description TEXT NOT NULL,
ts tsvector GENERATED ALWAYS AS ((
setweight(to_tsvector('english', (title)::TEXT), 'A') ||
setweight(to_tsvector('english', (description)::TEXT), 'B')
)) STORED
);
CREATE INDEX IF NOT EXISTS ts_idx ON catalog.upcoming_auctions_fts USING GIN(ts);
-- +goose StatementBegin
CREATE OR REPLACE FUNCTION catalog.bh_import_auction(
p_fingerprint VARCHAR(128),
p_title VARCHAR(1024),
p_startts TIMESTAMP,
p_endts TIMESTAMP,
p_description TEXT,
p_itemcount INTEGER,
p_sourcesiteurl VARCHAR(1024),
p_sourcesitename VARCHAR(256),
p_sourceurl VARCHAR(1024),
p_country VARCHAR(64),
p_province VARCHAR(128))
RETURNS INTEGER
LANGUAGE plpgsql AS $BODY$
DECLARE
auction_id INTEGER;
BEGIN
SELECT ua.id INTO auction_id FROM catalog.upcoming_auctions ua WHERE ua.fingerprint = p_fingerprint;
IF auction_id IS NULL OR auction_id = 0 THEN
INSERT INTO catalog.upcoming_auctions (
fingerprint,
title,
description,
startts,
endts,
itemcount,
sourcesiteurl,
sourcesitename,
sourceurl,
country,
province
) VALUES (
p_fingerprint,
p_title,
p_description,
p_startts,
p_endts,
p_itemcount,
p_sourcesiteurl,
p_sourcesitename,
p_sourceurl,
p_country,
p_province
) RETURNING id INTO auction_id;
INSERT INTO catalog.upcoming_auctions_fts (
auctionid,
title,
description
) VALUES ( auction_id, p_title, p_description );
ELSE
-- 0 means there is a duplicate auction ID
auction_id = 0;
END IF;
RETURN auction_id;
END;
$BODY$;
-- +goose StatementEnd
-- +goose StatementBegin
DO
$do$
BEGIN
IF NOT EXISTS (
SELECT FROM pg_catalog.pg_roles
WHERE rolname = 'catalog-service') THEN
CREATE USER "catalog-service" WITH PASSWORD 'catalog-service';
END IF;
END
$do$;
-- +goose StatementEnd
GRANT CONNECT ON DATABASE bh to "catalog-service";
GRANT USAGE ON SCHEMA catalog TO "catalog-service";
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA catalog TO "catalog-service";
GRANT SELECT, INSERT, UPDATE ON ALL TABLES IN SCHEMA catalog TO "catalog-service";
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA catalog TO "catalog-service";
COMMIT;
-- +goose Down

@ -0,0 +1,38 @@
-- +goose Up
START TRANSACTION;
CREATE SCHEMA IF NOT EXISTS runner;
CREATE TABLE IF NOT EXISTS runner.scrapejob (
id SERIAL PRIMARY KEY,
startedTs TIMESTAMP NOT NULL DEFAULT NOW(),
completedTs TIMESTAMP,
targetSiteName VARCHAR(512) NOT NULL,
auctionsFound INT NOT NULL DEFAULT 0,
errors TEXT NOT NULL DEFAULT ''
);
-- +goose StatementBegin
DO
$do$
BEGIN
IF NOT EXISTS (
SELECT FROM pg_catalog.pg_roles
WHERE rolname = 'runner-service') THEN
CREATE USER "runner-service" WITH PASSWORD 'runner-service';
END IF;
END
$do$;
-- +goose StatementEnd
GRANT CONNECT ON DATABASE bh to "runner-service";
GRANT USAGE ON SCHEMA runner TO "runner-service";
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA runner TO "runner-service";
GRANT SELECT, INSERT, UPDATE ON ALL TABLES IN SCHEMA runner TO "runner-service";
COMMIT;
-- +goose Down
Loading…
Cancel
Save