diff --git a/Models-and-Data/create.sql b/Models-and-Data/create.sql new file mode 100644 index 0000000..1fcc735 --- /dev/null +++ b/Models-and-Data/create.sql @@ -0,0 +1,124 @@ +CREATE TYPE "status" AS ENUM ( + 'SUBMITTED', + 'UNDER_REVIEW', + 'REVISION', + 'RESUBMITTED', + 'REJECTED', + 'ACCEPTED', + 'PUBLISHED' +); + +CREATE TABLE "person" ( + "email" text PRIMARY KEY, + "first_name" text NOT NULL, + "last_name" text NOT NULL +); + +CREATE TABLE "affiliation" ( + "org_name" text PRIMARY KEY, + "website" text NOT NULL, + "country" text NOT NULL +); + +CREATE TABLE "person_affiliation" ( + "email" text, + "org_name" text, + "from_date" date, + "to_date" date, + PRIMARY KEY ("email", "org_name") +); + +CREATE TABLE "paper" ( + "paper_id" INT GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, + "title" text NOT NULL, + "abstract" text NOT NULL, + "filename" text NOT NULL, + "contact_email" text NOT NULL, + "year" int NOT NULL +); + +CREATE TABLE "paper_author" ( + "paper_id" int, + "email" text, + "rank" int NOT NULL, + PRIMARY KEY ("paper_id", "email") +); + +CREATE TABLE "conference" ( + "year" int PRIMARY KEY, + "location" text NOT NULL +); + +CREATE TABLE "review" ( + "paper_id" int, + "email" text, + "merit" int NOT NULL, + "relevance" int NOT NULL, + "readability" int NOT NULL, + "originality" int NOT NULL, + "author_comments" text NOT NULL, + "committee_comments" text, + PRIMARY KEY ("paper_id", "email") +); + +CREATE TABLE "reviewer" ( + "email" text PRIMARY KEY, + "phone" text +); + +CREATE TABLE "topic" ( + "topic_id" INT GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, + "topic_name" text NOT NULL +); + +CREATE TABLE "paper_topic" ( + "paper_id" int, + "topic_id" int, + PRIMARY KEY ("paper_id", "topic_id") +); + +CREATE TABLE "expertise" ( + "email" text, + "topic_id" int, + PRIMARY KEY ("email", "topic_id") +); + +CREATE TABLE "history" ( + "paper_id" int, + "timestamp" timestamp, + "paper_status" status NOT NULL, + "notes" text, + PRIMARY KEY ("paper_id", "timestamp") +); + +COMMENT ON COLUMN "paper_author"."rank" IS 'author order'; + +COMMENT ON TABLE "review" IS 'Scores range from 1 to 5'; + +ALTER TABLE "person_affiliation" ADD FOREIGN KEY ("email") REFERENCES "person" ("email"); + +ALTER TABLE "person_affiliation" ADD FOREIGN KEY ("org_name") REFERENCES "affiliation" ("org_name"); + +ALTER TABLE "paper" ADD FOREIGN KEY ("contact_email") REFERENCES "person" ("email"); + +ALTER TABLE "paper" ADD FOREIGN KEY ("year") REFERENCES "conference" ("year"); + +ALTER TABLE "paper_author" ADD FOREIGN KEY ("paper_id") REFERENCES "paper" ("paper_id"); + +ALTER TABLE "paper_author" ADD FOREIGN KEY ("email") REFERENCES "person" ("email"); + +ALTER TABLE "review" ADD FOREIGN KEY ("paper_id") REFERENCES "paper" ("paper_id"); + +ALTER TABLE "review" ADD FOREIGN KEY ("email") REFERENCES "reviewer" ("email"); + +ALTER TABLE "reviewer" ADD FOREIGN KEY ("email") REFERENCES "person" ("email"); + +ALTER TABLE "paper_topic" ADD FOREIGN KEY ("paper_id") REFERENCES "paper" ("paper_id"); + +ALTER TABLE "paper_topic" ADD FOREIGN KEY ("topic_id") REFERENCES "topic" ("topic_id"); + +ALTER TABLE "expertise" ADD FOREIGN KEY ("email") REFERENCES "reviewer" ("email"); + +ALTER TABLE "expertise" ADD FOREIGN KEY ("topic_id") REFERENCES "topic" ("topic_id"); + +ALTER TABLE "history" ADD FOREIGN KEY ("paper_id") REFERENCES "paper" ("paper_id"); diff --git a/Models-and-Data/crs.dbml b/Models-and-Data/crs.dbml new file mode 100644 index 0000000..64ffe92 --- /dev/null +++ b/Models-and-Data/crs.dbml @@ -0,0 +1,116 @@ +// people and affiliations + +Table person { + email text [PK] + first_name text [not null] + last_name text [not null] +} + +Table affiliation { + org_name text [PK] + website text [not null] + country text [not null] +} + +Table person_affiliation { + email text [PK] + org_name text [PK] + from_date date + to_date date +} + +Ref: person_affiliation.email > person.email +Ref: person_affiliation.org_name > affiliation.org_name + +// papers and authors + +Table paper { + paper_id int [PK, increment] + title text [not null] + abstract text [not null] + filename text [not null] + contact_email text [not null] + year int [not null] +} + +Table paper_author { + paper_id int [PK] + email text [PK] + rank int [not null, note: "author order"] +} + +Table conference { + year int [PK] + location text [not null] +} + +Ref: paper.contact_email > person.email +Ref: paper.year > conference.year +Ref: paper_author.paper_id > paper.paper_id +Ref: paper_author.email > person.email + +// reviews and reviewers + +Table review { + paper_id int [PK] + email text [PK] + merit int [not null] + relevance int [not null] + readability int [not null] + originality int [not null] + author_comments text [not null] + committee_comments text + note: "Scores range from 1 to 5" +} + +Table reviewer { + email text [PK] + phone text +} + +Ref: review.paper_id > paper.paper_id +Ref: review.email > reviewer.email +Ref: person.email - reviewer.email + +// match papers with reviewers + +Table topic { + topic_id int [PK, increment] + topic_name text [not null] +} + +Table paper_topic { + paper_id int [PK] + topic_id int [PK] +} + +Table expertise { + email text [PK] + topic_id int [PK] +} + +Ref: paper_topic.paper_id > paper.paper_id +Ref: paper_topic.topic_id > topic.topic_id +Ref: expertise.email > reviewer.email +Ref: expertise.topic_id > topic.topic_id + +// history of status changes + +Enum status { + SUBMITTED + UNDER_REVIEW + REVISION + RESUBMITTED + REJECTED + ACCEPTED + PUBLISHED +} + +Table history { + paper_id int [PK] + timestamp timestamp [PK] + paper_status status [not null] + notes text +} + +Ref: history.paper_id > paper.paper_id diff --git a/Models-and-Data/drop.sql b/Models-and-Data/drop.sql new file mode 100644 index 0000000..298a010 --- /dev/null +++ b/Models-and-Data/drop.sql @@ -0,0 +1,13 @@ +DROP TABLE IF EXISTS person_affiliation; +DROP TABLE IF EXISTS affiliation; +DROP TABLE IF EXISTS paper_author; +DROP TABLE IF EXISTS review; +DROP TABLE IF EXISTS paper_topic; +DROP TABLE IF EXISTS expertise; +DROP TABLE IF EXISTS topic; +DROP TABLE IF EXISTS reviewer; +DROP TABLE IF EXISTS history; +DROP TABLE IF EXISTS paper; +DROP TABLE IF EXISTS person; +DROP TABLE IF EXISTS conference; +DROP TYPE IF EXISTS status; diff --git a/Models-and-Data/fakedata.py b/Models-and-Data/fakedata.py new file mode 100644 index 0000000..d29187c --- /dev/null +++ b/Models-and-Data/fakedata.py @@ -0,0 +1,189 @@ +"""Generate fake data for the Conference Review System.""" + +__author__ = "Nicholas Tamassia" + + +import random + +from faker import Faker +from sqlalchemy import create_engine +from sqlalchemy.orm import Session, sessionmaker + +from models import ( + Affiliation, + Base, + Conference, + History, + Paper, + PaperAuthor, + Person, + PersonAffiliation, + Review, + Reviewer, + Topic, + t_expertise, + t_paper_topic, +) + +DB_URL = "postgresql+psycopg://tamassno:113880616@localhost/sec2" + +fake = Faker() + + +def add_data(session: Session): + affiliations: list[Affiliation] = [] + for _ in range(4): + aff = Affiliation( + org_name=fake.company(), website=fake.url(), country=fake.country() + ) + affiliations.append(aff) + session.add_all(affiliations) + session.commit() + + persons: list[Person] = [] + reviewers: list[Reviewer] = [] + + for _ in range(5): + p = Person( + email=fake.unique.email(), + first_name=fake.first_name(), + last_name=fake.last_name(), + ) + persons.append(p) + + for _ in range(5): + r = Reviewer( + email=fake.unique.email(), + first_name=fake.first_name(), + last_name=fake.last_name(), + phone=fake.phone_number(), + ) + reviewers.append(r) + + session.add_all(persons + reviewers) + session.commit() + + person_affiliations: list[PersonAffiliation] = [] + people_pool = random.sample(persons + reviewers, 8) + for person in people_pool: + aff = random.choice(affiliations) + pa = PersonAffiliation( + email=person.email, + org_name=aff.org_name, + from_date=fake.date_between(start_date="-5y", end_date="-1y"), + to_date=fake.date_between(start_date="-1y", end_date="today"), + ) + person_affiliations.append(pa) + session.add_all(person_affiliations) + session.commit() + + conference = Conference(year=2025, location=fake.city()) + session.add(conference) + session.commit() + + topics: list[Topic] = [] + for _ in range(20): + t = Topic(topic_name=fake.bs().title()) + topics.append(t) + session.add_all(topics) + session.commit() + + papers: list[Paper] = [] + for _ in range(3): + contact = random.choice(persons + reviewers) + p = Paper( + title=fake.sentence(nb_words=6), + abstract=fake.paragraph(nb_sentences=3), + filename=f"{fake.word()}.pdf", + contact_email=contact.email, + year=conference.year, + ) + papers.append(p) + session.add_all(papers) + session.commit() + + paper_authors: list[PaperAuthor] = [] + for _ in range(8): + paper = random.choice(papers) + author = random.choice(persons + reviewers) + pa = PaperAuthor( + paper_id=paper.paper_id, email=author.email, rank=random.randint(1, 5) + ) + paper_authors.append(pa) + session.add_all(paper_authors) + session.commit() + + paper_topic_data: list[dict[str, int]] = [] + used_pairs: set[tuple[int, int]] = set() + while len(paper_topic_data) < 9: + paper = random.choice(papers) + topic = random.choice(topics) + if (paper.paper_id, topic.topic_id) not in used_pairs: + used_pairs.add((paper.paper_id, topic.topic_id)) + paper_topic_data.append( + {"paper_id": paper.paper_id, "topic_id": topic.topic_id} + ) + _ = session.execute(t_paper_topic.insert(), paper_topic_data) + session.commit() + + expertise_data: list[dict[str, str | int]] = [] + used_expertise: set[tuple[str, int]] = set() + while len(expertise_data) < 10: + reviewer = random.choice(reviewers) + topic = random.choice(topics) + if (reviewer.email, topic.topic_id) not in used_expertise: + used_expertise.add((reviewer.email, topic.topic_id)) + expertise_data.append({"email": reviewer.email, "topic_id": topic.topic_id}) + _ = session.execute(t_expertise.insert(), expertise_data) + session.commit() + + reviews: list[Review] = [] + posible_reviews = [ + (paper.paper_id, reviewer.email) for paper in papers for reviewer in reviewers + ] + for _ in range(3): + paper_id, email = random.choice(posible_reviews) + rv = Review( + paper_id=paper_id, + email=email, + merit=random.randint(1, 5), + relevance=random.randint(1, 5), + readability=random.randint(1, 5), + originality=random.randint(1, 5), + author_comments=fake.sentence(), + committee_comments=fake.sentence(), + ) + reviews.append(rv) + session.add_all(reviews) + session.commit() + + statuses = ["SUBMITTED", "UNDER_REVIEW", "REVISION", "ACCEPTED", "PUBLISHED"] + histories: list[History] = [] + for _ in range(5): + paper = random.choice(papers) + h = History( + paper_id=paper.paper_id, + timestamp=fake.date_time_between(start_date="-1y", end_date="now"), + paper_status=random.choice(statuses), + notes=fake.sentence(), + ) + histories.append(h) + session.add_all(histories) + session.commit() + + +def main(): + engine = create_engine(DB_URL) + Base.metadata.drop_all(engine) + Base.metadata.create_all(engine) + + Session = sessionmaker(bind=engine) + session = Session() + + add_data(session) + + session.close() + + +if __name__ == "__main__": + main() diff --git a/Models-and-Data/models.py b/Models-and-Data/models.py new file mode 100644 index 0000000..837a60e --- /dev/null +++ b/Models-and-Data/models.py @@ -0,0 +1,188 @@ +from typing import Optional +import datetime + +from sqlalchemy import Column, Date, DateTime, Enum, ForeignKeyConstraint, Identity, Integer, PrimaryKeyConstraint, Table, Text +from sqlalchemy.orm import DeclarativeBase, Mapped, mapped_column, relationship + +class Base(DeclarativeBase): + pass + + +class Affiliation(Base): + __tablename__ = 'affiliation' + __table_args__ = ( + PrimaryKeyConstraint('org_name', name='affiliation_pkey'), + ) + + org_name: Mapped[str] = mapped_column(Text, primary_key=True) + website: Mapped[str] = mapped_column(Text, nullable=False) + country: Mapped[str] = mapped_column(Text, nullable=False) + + person_affiliation: Mapped[list['PersonAffiliation']] = relationship('PersonAffiliation', back_populates='affiliation') + + +class Conference(Base): + __tablename__ = 'conference' + __table_args__ = ( + PrimaryKeyConstraint('year', name='conference_pkey'), + ) + + year: Mapped[int] = mapped_column(Integer, primary_key=True) + location: Mapped[str] = mapped_column(Text, nullable=False) + + paper: Mapped[list['Paper']] = relationship('Paper', back_populates='conference') + + +class Person(Base): + __tablename__ = 'person' + __table_args__ = ( + PrimaryKeyConstraint('email', name='person_pkey'), + ) + + email: Mapped[str] = mapped_column(Text, primary_key=True) + first_name: Mapped[str] = mapped_column(Text, nullable=False) + last_name: Mapped[str] = mapped_column(Text, nullable=False) + + paper: Mapped[list['Paper']] = relationship('Paper', back_populates='person') + person_affiliation: Mapped[list['PersonAffiliation']] = relationship('PersonAffiliation', back_populates='person') + paper_author: Mapped[list['PaperAuthor']] = relationship('PaperAuthor', back_populates='person') + + +class Topic(Base): + __tablename__ = 'topic' + __table_args__ = ( + PrimaryKeyConstraint('topic_id', name='topic_pkey'), + ) + + topic_id: Mapped[int] = mapped_column(Integer, Identity(start=1, increment=1, minvalue=1, maxvalue=2147483647, cycle=False, cache=1), primary_key=True) + topic_name: Mapped[str] = mapped_column(Text, nullable=False) + + paper: Mapped[list['Paper']] = relationship('Paper', secondary='paper_topic', back_populates='topic') + reviewer: Mapped[list['Reviewer']] = relationship('Reviewer', secondary='expertise', back_populates='topic') + + +class Paper(Base): + __tablename__ = 'paper' + __table_args__ = ( + ForeignKeyConstraint(['contact_email'], ['person.email'], name='paper_contact_email_fkey'), + ForeignKeyConstraint(['year'], ['conference.year'], name='paper_year_fkey'), + PrimaryKeyConstraint('paper_id', name='paper_pkey') + ) + + paper_id: Mapped[int] = mapped_column(Integer, Identity(start=1, increment=1, minvalue=1, maxvalue=2147483647, cycle=False, cache=1), primary_key=True) + title: Mapped[str] = mapped_column(Text, nullable=False) + abstract: Mapped[str] = mapped_column(Text, nullable=False) + filename: Mapped[str] = mapped_column(Text, nullable=False) + contact_email: Mapped[str] = mapped_column(Text, nullable=False) + year: Mapped[int] = mapped_column(Integer, nullable=False) + + person: Mapped['Person'] = relationship('Person', back_populates='paper') + conference: Mapped['Conference'] = relationship('Conference', back_populates='paper') + topic: Mapped[list['Topic']] = relationship('Topic', secondary='paper_topic', back_populates='paper') + history: Mapped[list['History']] = relationship('History', back_populates='paper') + paper_author: Mapped[list['PaperAuthor']] = relationship('PaperAuthor', back_populates='paper') + review: Mapped[list['Review']] = relationship('Review', back_populates='paper') + + +class PersonAffiliation(Base): + __tablename__ = 'person_affiliation' + __table_args__ = ( + ForeignKeyConstraint(['email'], ['person.email'], name='person_affiliation_email_fkey'), + ForeignKeyConstraint(['org_name'], ['affiliation.org_name'], name='person_affiliation_org_name_fkey'), + PrimaryKeyConstraint('email', 'org_name', name='person_affiliation_pkey') + ) + + email: Mapped[str] = mapped_column(Text, primary_key=True) + org_name: Mapped[str] = mapped_column(Text, primary_key=True) + from_date: Mapped[Optional[datetime.date]] = mapped_column(Date) + to_date: Mapped[Optional[datetime.date]] = mapped_column(Date) + + person: Mapped['Person'] = relationship('Person', back_populates='person_affiliation') + affiliation: Mapped['Affiliation'] = relationship('Affiliation', back_populates='person_affiliation') + + +class Reviewer(Person): + __tablename__ = 'reviewer' + __table_args__ = ( + ForeignKeyConstraint(['email'], ['person.email'], name='reviewer_email_fkey'), + PrimaryKeyConstraint('email', name='reviewer_pkey') + ) + + email: Mapped[str] = mapped_column(Text, primary_key=True) + phone: Mapped[Optional[str]] = mapped_column(Text) + + topic: Mapped[list['Topic']] = relationship('Topic', secondary='expertise', back_populates='reviewer') + review: Mapped[list['Review']] = relationship('Review', back_populates='reviewer') + + +t_expertise = Table( + 'expertise', Base.metadata, + Column('email', Text, primary_key=True), + Column('topic_id', Integer, primary_key=True), + ForeignKeyConstraint(['email'], ['reviewer.email'], name='expertise_email_fkey'), + ForeignKeyConstraint(['topic_id'], ['topic.topic_id'], name='expertise_topic_id_fkey'), + PrimaryKeyConstraint('email', 'topic_id', name='expertise_pkey') +) + + +class History(Base): + __tablename__ = 'history' + __table_args__ = ( + ForeignKeyConstraint(['paper_id'], ['paper.paper_id'], name='history_paper_id_fkey'), + PrimaryKeyConstraint('paper_id', 'timestamp', name='history_pkey') + ) + + paper_id: Mapped[int] = mapped_column(Integer, primary_key=True) + timestamp: Mapped[datetime.datetime] = mapped_column(DateTime, primary_key=True) + paper_status: Mapped[str] = mapped_column(Enum('SUBMITTED', 'UNDER_REVIEW', 'REVISION', 'RESUBMITTED', 'REJECTED', 'ACCEPTED', 'PUBLISHED', name='status'), nullable=False) + notes: Mapped[Optional[str]] = mapped_column(Text) + + paper: Mapped['Paper'] = relationship('Paper', back_populates='history') + + +class PaperAuthor(Base): + __tablename__ = 'paper_author' + __table_args__ = ( + ForeignKeyConstraint(['email'], ['person.email'], name='paper_author_email_fkey'), + ForeignKeyConstraint(['paper_id'], ['paper.paper_id'], name='paper_author_paper_id_fkey'), + PrimaryKeyConstraint('paper_id', 'email', name='paper_author_pkey') + ) + + paper_id: Mapped[int] = mapped_column(Integer, primary_key=True) + email: Mapped[str] = mapped_column(Text, primary_key=True) + rank: Mapped[int] = mapped_column(Integer, nullable=False, comment='author order') + + person: Mapped['Person'] = relationship('Person', back_populates='paper_author') + paper: Mapped['Paper'] = relationship('Paper', back_populates='paper_author') + + +t_paper_topic = Table( + 'paper_topic', Base.metadata, + Column('paper_id', Integer, primary_key=True), + Column('topic_id', Integer, primary_key=True), + ForeignKeyConstraint(['paper_id'], ['paper.paper_id'], name='paper_topic_paper_id_fkey'), + ForeignKeyConstraint(['topic_id'], ['topic.topic_id'], name='paper_topic_topic_id_fkey'), + PrimaryKeyConstraint('paper_id', 'topic_id', name='paper_topic_pkey') +) + + +class Review(Base): + __tablename__ = 'review' + __table_args__ = ( + ForeignKeyConstraint(['email'], ['reviewer.email'], name='review_email_fkey'), + ForeignKeyConstraint(['paper_id'], ['paper.paper_id'], name='review_paper_id_fkey'), + PrimaryKeyConstraint('paper_id', 'email', name='review_pkey'), + {'comment': 'Scores range from 1 to 5'} + ) + + paper_id: Mapped[int] = mapped_column(Integer, primary_key=True) + email: Mapped[str] = mapped_column(Text, primary_key=True) + merit: Mapped[int] = mapped_column(Integer, nullable=False) + relevance: Mapped[int] = mapped_column(Integer, nullable=False) + readability: Mapped[int] = mapped_column(Integer, nullable=False) + originality: Mapped[int] = mapped_column(Integer, nullable=False) + author_comments: Mapped[str] = mapped_column(Text, nullable=False) + committee_comments: Mapped[Optional[str]] = mapped_column(Text) + + reviewer: Mapped['Reviewer'] = relationship('Reviewer', back_populates='review') + paper: Mapped['Paper'] = relationship('Paper', back_populates='review') diff --git a/devenv.lock b/devenv.lock index 854c55b..6347cd8 100644 --- a/devenv.lock +++ b/devenv.lock @@ -3,10 +3,10 @@ "devenv": { "locked": { "dir": "src/modules", - "lastModified": 1759178241, + "lastModified": 1760987569, "owner": "cachix", "repo": "devenv", - "rev": "11aec9c56d7538301edb74e01b86d2f5ada42996", + "rev": "829e3dba0dbf0f50772f95e683e5aeb9c93f0314", "type": "github" }, "original": { @@ -40,10 +40,10 @@ ] }, "locked": { - "lastModified": 1758108966, + "lastModified": 1760663237, "owner": "cachix", "repo": "git-hooks.nix", - "rev": "54df955a695a84cd47d4a43e08e1feaf90b1fd9b", + "rev": "ca5b894d3e3e151ffc1db040b6ce4dcc75d31c37", "type": "github" }, "original": { diff --git a/devenv.nix b/devenv.nix index 92af639..e39f1eb 100644 --- a/devenv.nix +++ b/devenv.nix @@ -2,7 +2,10 @@ { # https://devenv.sh/packages/ - packages = [ pkgs.git ]; + packages = with pkgs; [ + git + pgadmin4-desktopmode + ]; # https://devenv.sh/languages/ languages.python = { @@ -10,14 +13,11 @@ venv = { enable = true; requirements = '' - Faker==37.8.0 - greenlet==3.2.4 - psycopg==3.2.10 - psycopg-binary==3.2.10 + sqlacodegen==3.1.1 + Faker==37.11.0 python-dotenv==1.1.1 - SQLAlchemy==2.0.44 - typing_extensions==4.15.0 - tzdata==2025.2 + psycopg==3.2.11 + psycopg-binary==3.2.11 ''; }; };