390 lines
14 KiB
TypeScript
390 lines
14 KiB
TypeScript
import { Table, TableForeignKey, TableUnique, View } from "typeorm";
|
|
import { getDefaultByORM, getTypeByORM, isIncrementPrimary, isUUIDPrimary } from "../ormHelper";
|
|
|
|
export const salutation_table = new Table({
|
|
name: "salutation",
|
|
columns: [
|
|
{ name: "id", ...getTypeByORM("int"), ...isIncrementPrimary },
|
|
{ name: "salutation", ...getTypeByORM("varchar"), isUnique: true },
|
|
],
|
|
});
|
|
|
|
export const award_table = new Table({
|
|
name: "award",
|
|
columns: [
|
|
{ name: "id", ...getTypeByORM("int"), ...isIncrementPrimary },
|
|
{ name: "award", ...getTypeByORM("varchar"), isUnique: true },
|
|
],
|
|
});
|
|
|
|
export const communication_type_table = new Table({
|
|
name: "communication_type",
|
|
columns: [
|
|
{ name: "id", ...getTypeByORM("int"), ...isIncrementPrimary },
|
|
{ name: "type", ...getTypeByORM("varchar"), isUnique: true },
|
|
{ name: "useColumns", ...getTypeByORM("varchar"), default: getDefaultByORM("string") },
|
|
],
|
|
});
|
|
|
|
export const executive_position_table = new Table({
|
|
name: "executive_position",
|
|
columns: [
|
|
{ name: "id", ...getTypeByORM("int"), ...isIncrementPrimary },
|
|
{ name: "position", ...getTypeByORM("varchar"), isUnique: true },
|
|
],
|
|
});
|
|
|
|
export const membership_status_table = new Table({
|
|
name: "membership_status",
|
|
columns: [
|
|
{ name: "id", ...getTypeByORM("int"), ...isIncrementPrimary },
|
|
{ name: "status", ...getTypeByORM("varchar"), isUnique: true },
|
|
],
|
|
});
|
|
|
|
export const qualification_table = new Table({
|
|
name: "qualification",
|
|
columns: [
|
|
{ name: "id", ...getTypeByORM("int"), ...isIncrementPrimary },
|
|
{ name: "qualification", ...getTypeByORM("varchar"), isUnique: true },
|
|
{ name: "description", ...getTypeByORM("varchar"), isNullable: true },
|
|
],
|
|
});
|
|
|
|
export const education_table = new Table({
|
|
name: "education",
|
|
columns: [
|
|
{ name: "id", ...getTypeByORM("int"), ...isIncrementPrimary },
|
|
{ name: "education", ...getTypeByORM("varchar"), isUnique: true },
|
|
{ name: "description", ...getTypeByORM("varchar"), isNullable: true },
|
|
],
|
|
});
|
|
|
|
/** member and relations */
|
|
export const member_table = new Table({
|
|
name: "member",
|
|
columns: [
|
|
{ name: "id", ...getTypeByORM("uuid"), ...isUUIDPrimary },
|
|
{ name: "salutationId", ...getTypeByORM("int") },
|
|
{ name: "internalId", ...getTypeByORM("varchar", true) },
|
|
{ name: "firstname", ...getTypeByORM("varchar") },
|
|
{ name: "lastname", ...getTypeByORM("varchar") },
|
|
{ name: "nameaffix", ...getTypeByORM("varchar") },
|
|
{ name: "birthdate", ...getTypeByORM("date") },
|
|
{ name: "createdAt", ...getTypeByORM("datetime", false, 6), default: getDefaultByORM("currentTimestamp", 6) },
|
|
{ name: "note", ...getTypeByORM("varchar", true) },
|
|
],
|
|
foreignKeys: [
|
|
new TableForeignKey({
|
|
columnNames: ["salutationId"],
|
|
referencedColumnNames: ["id"],
|
|
referencedTableName: "salutation",
|
|
onDelete: "RESTRICT",
|
|
onUpdate: "RESTRICT",
|
|
}),
|
|
],
|
|
uniques: [
|
|
new TableUnique({
|
|
columnNames: ["internalId"],
|
|
}),
|
|
],
|
|
});
|
|
|
|
export const membership_table = new Table({
|
|
name: "membership",
|
|
columns: [
|
|
{ name: "id", ...getTypeByORM("int"), ...isIncrementPrimary },
|
|
{ name: "start", ...getTypeByORM("date") },
|
|
{ name: "end", ...getTypeByORM("date", true) },
|
|
{ name: "terminationReason", ...getTypeByORM("varchar"), isNullable: true },
|
|
{ name: "memberId", ...getTypeByORM("uuid") },
|
|
{ name: "statusId", ...getTypeByORM("int") },
|
|
],
|
|
foreignKeys: [
|
|
new TableForeignKey({
|
|
columnNames: ["memberId"],
|
|
referencedTableName: "member",
|
|
referencedColumnNames: ["id"],
|
|
onDelete: "CASCADE",
|
|
onUpdate: "RESTRICT",
|
|
}),
|
|
new TableForeignKey({
|
|
columnNames: ["statusId"],
|
|
referencedTableName: "membership_status",
|
|
referencedColumnNames: ["id"],
|
|
onDelete: "RESTRICT",
|
|
onUpdate: "RESTRICT",
|
|
}),
|
|
],
|
|
});
|
|
|
|
export const member_qualifications_table = new Table({
|
|
name: "member_qualifications",
|
|
columns: [
|
|
{ name: "id", ...getTypeByORM("int"), ...isIncrementPrimary },
|
|
{ name: "note", ...getTypeByORM("varchar"), isNullable: true },
|
|
{ name: "start", ...getTypeByORM("date") },
|
|
{ name: "end", ...getTypeByORM("date", true) },
|
|
{ name: "terminationReason", ...getTypeByORM("varchar"), isNullable: true },
|
|
{ name: "memberId", ...getTypeByORM("uuid") },
|
|
{ name: "qualificationId", ...getTypeByORM("int") },
|
|
],
|
|
foreignKeys: [
|
|
new TableForeignKey({
|
|
columnNames: ["memberId"],
|
|
referencedTableName: "member",
|
|
referencedColumnNames: ["id"],
|
|
onDelete: "CASCADE",
|
|
onUpdate: "RESTRICT",
|
|
}),
|
|
new TableForeignKey({
|
|
columnNames: ["qualificationId"],
|
|
referencedTableName: "qualification",
|
|
referencedColumnNames: ["id"],
|
|
onDelete: "RESTRICT",
|
|
onUpdate: "RESTRICT",
|
|
}),
|
|
],
|
|
});
|
|
|
|
export const member_executive_positions_table = new Table({
|
|
name: "member_executive_positions",
|
|
columns: [
|
|
{ name: "id", ...getTypeByORM("int"), ...isIncrementPrimary },
|
|
{ name: "note", ...getTypeByORM("varchar"), isNullable: true },
|
|
{ name: "start", ...getTypeByORM("date") },
|
|
{ name: "end", ...getTypeByORM("date", true) },
|
|
{ name: "memberId", ...getTypeByORM("uuid") },
|
|
{ name: "executivePositionId", ...getTypeByORM("int") },
|
|
],
|
|
foreignKeys: [
|
|
new TableForeignKey({
|
|
columnNames: ["memberId"],
|
|
referencedTableName: "member",
|
|
referencedColumnNames: ["id"],
|
|
onDelete: "CASCADE",
|
|
onUpdate: "RESTRICT",
|
|
}),
|
|
new TableForeignKey({
|
|
columnNames: ["executivePositionId"],
|
|
referencedTableName: "executive_position",
|
|
referencedColumnNames: ["id"],
|
|
onDelete: "RESTRICT",
|
|
onUpdate: "RESTRICT",
|
|
}),
|
|
],
|
|
});
|
|
|
|
export const member_awards_table = new Table({
|
|
name: "member_awards",
|
|
columns: [
|
|
{ name: "id", ...getTypeByORM("int"), ...isIncrementPrimary },
|
|
{ name: "given", ...getTypeByORM("boolean"), default: getDefaultByORM("boolean", true) },
|
|
{ name: "note", ...getTypeByORM("varchar"), isNullable: true },
|
|
{ name: "date", ...getTypeByORM("date") },
|
|
{ name: "memberId", ...getTypeByORM("uuid") },
|
|
{ name: "awardId", ...getTypeByORM("int") },
|
|
],
|
|
foreignKeys: [
|
|
new TableForeignKey({
|
|
columnNames: ["memberId"],
|
|
referencedTableName: "member",
|
|
referencedColumnNames: ["id"],
|
|
onDelete: "CASCADE",
|
|
onUpdate: "RESTRICT",
|
|
}),
|
|
new TableForeignKey({
|
|
columnNames: ["awardId"],
|
|
referencedTableName: "award",
|
|
referencedColumnNames: ["id"],
|
|
onDelete: "RESTRICT",
|
|
onUpdate: "RESTRICT",
|
|
}),
|
|
],
|
|
});
|
|
|
|
export const member_communication_table = new Table({
|
|
name: "communication",
|
|
columns: [
|
|
{ name: "id", ...getTypeByORM("int"), ...isIncrementPrimary },
|
|
{ name: "preferred", ...getTypeByORM("boolean"), default: getDefaultByORM("boolean", false) },
|
|
{ name: "isSendNewsletter", ...getTypeByORM("boolean"), default: getDefaultByORM("boolean", false) },
|
|
{ name: "isSMSAlarming", ...getTypeByORM("boolean"), default: getDefaultByORM("boolean", false) },
|
|
{ name: "mobile", ...getTypeByORM("varchar", true) },
|
|
{ name: "email", ...getTypeByORM("varchar", true) },
|
|
{ name: "postalCode", ...getTypeByORM("varchar", true) },
|
|
{ name: "city", ...getTypeByORM("varchar", true) },
|
|
{ name: "street", ...getTypeByORM("varchar", true) },
|
|
{ name: "streetNumber", ...getTypeByORM("int", true) },
|
|
{ name: "streetNumberAddition", ...getTypeByORM("varchar", true) },
|
|
{ name: "memberId", ...getTypeByORM("uuid") },
|
|
{ name: "typeId", ...getTypeByORM("int") },
|
|
],
|
|
foreignKeys: [
|
|
new TableForeignKey({
|
|
columnNames: ["memberId"],
|
|
referencedTableName: "member",
|
|
referencedColumnNames: ["id"],
|
|
onDelete: "CASCADE",
|
|
onUpdate: "RESTRICT",
|
|
}),
|
|
new TableForeignKey({
|
|
columnNames: ["typeId"],
|
|
referencedColumnNames: ["id"],
|
|
referencedTableName: "communication_type",
|
|
onDelete: "RESTRICT",
|
|
onUpdate: "RESTRICT",
|
|
}),
|
|
],
|
|
});
|
|
|
|
export const member_educations_table = new Table({
|
|
name: "member_educations",
|
|
columns: [
|
|
{ name: "id", ...getTypeByORM("int"), ...isIncrementPrimary },
|
|
{ name: "start", ...getTypeByORM("date") },
|
|
{ name: "end", ...getTypeByORM("date", true), default: getDefaultByORM("null") },
|
|
{ name: "note", ...getTypeByORM("varchar"), isNullable: true },
|
|
{ name: "place", ...getTypeByORM("varchar"), isNullable: true },
|
|
{ name: "memberId", ...getTypeByORM("uuid") },
|
|
{ name: "educationId", ...getTypeByORM("int") },
|
|
],
|
|
foreignKeys: [
|
|
new TableForeignKey({
|
|
columnNames: ["memberId"],
|
|
referencedTableName: "member",
|
|
referencedColumnNames: ["id"],
|
|
onDelete: "CASCADE",
|
|
onUpdate: "RESTRICT",
|
|
}),
|
|
new TableForeignKey({
|
|
columnNames: ["educationId"],
|
|
referencedTableName: "education",
|
|
referencedColumnNames: ["id"],
|
|
onDelete: "RESTRICT",
|
|
onUpdate: "RESTRICT",
|
|
}),
|
|
],
|
|
});
|
|
|
|
/** views */
|
|
|
|
export const member_view = new View({
|
|
name: "member_view",
|
|
expression: `
|
|
SELECT
|
|
"member"."id" AS "id",
|
|
"member"."firstname" AS "firstname",
|
|
"member"."lastname" AS "lastname",
|
|
"member"."nameaffix" AS "nameaffix",
|
|
"member"."birthdate" AS "birthdate",
|
|
"member"."internalId" AS "internalId",
|
|
"member"."note" AS "note",
|
|
"salutation"."salutation" AS "salutation",
|
|
DATE_PART('year', AGE(CURRENT_DATE, "member"."birthdate")) AS "todayAge",
|
|
EXTRACT(YEAR FROM CURRENT_DATE) - EXTRACT(YEAR FROM "member"."birthdate") AS "ageThisYear",
|
|
AGE(CURRENT_DATE, "member"."birthdate") AS "exactAge"
|
|
FROM "member" "member"
|
|
LEFT JOIN "salutation" "salutation" ON "salutation"."id"="member"."salutationId"
|
|
`
|
|
.replace(/\s+/g, " ")
|
|
.trim(),
|
|
});
|
|
|
|
export const member_executive_positions_view = new View({
|
|
name: "member_executive_positions_view",
|
|
expression: `
|
|
SELECT
|
|
"executivePosition"."id" AS "positionId",
|
|
"executivePosition"."position" AS "position",
|
|
"member"."id" AS "memberId",
|
|
"member"."firstname" AS "memberFirstname",
|
|
"member"."lastname" AS "memberLastname",
|
|
"member"."nameaffix" AS "memberNameaffix",
|
|
"member"."birthdate" AS "memberBirthdate",
|
|
"salutation"."salutation" AS "memberSalutation",
|
|
SUM(COALESCE("memberExecutivePositions"."end", CURRENT_DATE) - "memberExecutivePositions"."start") AS "durationInDays",
|
|
SUM(EXTRACT(YEAR FROM AGE(COALESCE("memberExecutivePositions"."end", CURRENT_DATE), "memberExecutivePositions"."start"))) AS "durationInYears",
|
|
SUM(AGE(COALESCE("memberExecutivePositions"."end", CURRENT_DATE), "memberExecutivePositions"."start")) AS "exactDuration"
|
|
FROM "member_executive_positions" "memberExecutivePositions"
|
|
LEFT JOIN "executive_position" "executivePosition" ON "executivePosition"."id"="memberExecutivePositions"."executivePositionId"
|
|
LEFT JOIN "member" "member" ON "member"."id"="memberExecutivePositions"."memberId"
|
|
LEFT JOIN "salutation" "salutation" ON "salutation"."id"="member"."salutationId"
|
|
GROUP BY "executivePosition"."id", "member"."id", "salutation"."id"
|
|
`
|
|
.replace(/\s+/g, " ")
|
|
.trim(),
|
|
});
|
|
|
|
export const member_qualifications_view = new View({
|
|
name: "member_qualifications_view",
|
|
expression: `
|
|
SELECT
|
|
"qualification"."id" AS "qualificationId",
|
|
"qualification"."qualification" AS "qualification",
|
|
"member"."id" AS "memberId",
|
|
"member"."firstname" AS "memberFirstname",
|
|
"member"."lastname" AS "memberLastname",
|
|
"member"."nameaffix" AS "memberNameaffix",
|
|
"member"."birthdate" AS "memberBirthdate",
|
|
"salutation"."salutation" AS "memberSalutation",
|
|
SUM(COALESCE("memberQualifications"."end", CURRENT_DATE) - "memberQualifications"."start") AS "durationInDays",
|
|
SUM(EXTRACT(YEAR FROM AGE(COALESCE("memberQualifications"."end", CURRENT_DATE), "memberQualifications"."start"))) AS "durationInYears",
|
|
SUM(AGE(COALESCE("memberQualifications"."end", CURRENT_DATE), "memberQualifications"."start")) AS "exactDuration"
|
|
FROM "member_qualifications" "memberQualifications"
|
|
LEFT JOIN "qualification" "qualification" ON "qualification"."id"="memberQualifications"."qualificationId"
|
|
LEFT JOIN "member" "member" ON "member"."id"="memberQualifications"."memberId"
|
|
LEFT JOIN "salutation" "salutation" ON "salutation"."id"="member"."salutationId"
|
|
GROUP BY "qualification"."id", "member"."id", "salutation"."id"
|
|
`
|
|
.replace(/\s+/g, " ")
|
|
.trim(),
|
|
});
|
|
|
|
export const membership_view = new View({
|
|
name: "membership_view",
|
|
expression: `
|
|
SELECT
|
|
"status"."id" AS "statusId",
|
|
"status"."status" AS "status",
|
|
"member"."id" AS "memberId",
|
|
"member"."firstname" AS "memberFirstname",
|
|
"member"."lastname" AS "memberLastname",
|
|
"member"."nameaffix" AS "memberNameaffix",
|
|
"member"."birthdate" AS "memberBirthdate",
|
|
"salutation"."salutation" AS "memberSalutation",
|
|
SUM(COALESCE("membership"."end", CURRENT_DATE) - "membership"."start") AS "durationInDays",
|
|
SUM(EXTRACT(YEAR FROM AGE(COALESCE("membership"."end", CURRENT_DATE), "membership"."start"))) AS "durationInYears",
|
|
SUM(AGE(COALESCE("membership"."end", CURRENT_DATE), "membership"."start")) AS "exactDuration"
|
|
FROM "membership" "membership"
|
|
LEFT JOIN "membership_status" "status" ON "status"."id"="membership"."statusId"
|
|
LEFT JOIN "member" "member" ON "member"."id"="membership"."memberId"
|
|
LEFT JOIN "salutation" "salutation" ON "salutation"."id"="member"."salutationId"
|
|
GROUP BY "status"."id", "member"."id", "salutation"."id"
|
|
`
|
|
.replace(/\s+/g, " ")
|
|
.trim(),
|
|
});
|
|
|
|
export const membership_total_view = new View({
|
|
name: "membership_total_view",
|
|
expression: `
|
|
SELECT
|
|
"member"."id" AS "memberId",
|
|
"member"."firstname" AS "memberFirstname",
|
|
"member"."lastname" AS "memberLastname",
|
|
"member"."nameaffix" AS "memberNameaffix",
|
|
"member"."birthdate" AS "memberBirthdate",
|
|
"salutation"."salutation" AS "memberSalutation",
|
|
SUM(COALESCE("membership"."end", CURRENT_DATE) - "membership"."start") AS "durationInDays",
|
|
SUM(EXTRACT(YEAR FROM AGE(COALESCE("membership"."end", CURRENT_DATE), "membership"."start"))) AS "durationInYears",
|
|
SUM(AGE(COALESCE("membership"."end", CURRENT_DATE), "membership"."start")) AS "exactDuration"
|
|
FROM "membership" "membership"
|
|
LEFT JOIN "membership_status" "status" ON "status"."id"="membership"."statusId"
|
|
LEFT JOIN "member" "member" ON "member"."id"="membership"."memberId"
|
|
LEFT JOIN "salutation" "salutation" ON "salutation"."id"="member"."salutationId"
|
|
GROUP BY "member"."id", "salutation"."id"
|
|
`
|
|
.replace(/\s+/g, " ")
|
|
.trim(),
|
|
});
|