2025-01-30 15:58:34 +01:00
import { Table , TableForeignKey , View } from "typeorm" ;
2025-02-01 13:11:10 +01:00
import { getDefaultByORM , getTypeByORM , isIncrementPrimary , isUUIDPrimary } from "../ormHelper" ;
2025-01-30 15:58:34 +01:00
export const salutation_table = new Table ( {
name : "salutation" ,
columns : [
2025-02-01 13:11:10 +01:00
{ name : "id" , . . . getTypeByORM ( "int" ) , . . . isIncrementPrimary } ,
{ name : "salutation" , . . . getTypeByORM ( "varchar" ) , isUnique : true } ,
2025-01-30 15:58:34 +01:00
] ,
} ) ;
export const award_table = new Table ( {
name : "award" ,
columns : [
2025-02-01 13:11:10 +01:00
{ name : "id" , . . . getTypeByORM ( "int" ) , . . . isIncrementPrimary } ,
{ name : "award" , . . . getTypeByORM ( "varchar" ) , isUnique : true } ,
2025-01-30 15:58:34 +01:00
] ,
} ) ;
export const communication_type_table = new Table ( {
name : "communication_type" ,
columns : [
2025-02-01 13:11:10 +01:00
{ name : "id" , . . . getTypeByORM ( "int" ) , . . . isIncrementPrimary } ,
{ name : "type" , . . . getTypeByORM ( "varchar" ) , isUnique : true } ,
{ name : "useColumns" , . . . getTypeByORM ( "varchar" ) , default : getDefaultByORM ( "string" ) } ,
2025-01-30 15:58:34 +01:00
] ,
} ) ;
export const executive_position_table = new Table ( {
name : "executive_position" ,
columns : [
2025-02-01 13:11:10 +01:00
{ name : "id" , . . . getTypeByORM ( "int" ) , . . . isIncrementPrimary } ,
{ name : "position" , . . . getTypeByORM ( "varchar" ) , isUnique : true } ,
2025-01-30 15:58:34 +01:00
] ,
} ) ;
export const membership_status_table = new Table ( {
name : "membership_status" ,
columns : [
2025-02-01 13:11:10 +01:00
{ name : "id" , . . . getTypeByORM ( "int" ) , . . . isIncrementPrimary } ,
{ name : "status" , . . . getTypeByORM ( "varchar" ) , isUnique : true } ,
2025-01-30 15:58:34 +01:00
] ,
} ) ;
export const qualification_table = new Table ( {
name : "qualification" ,
columns : [
2025-02-01 13:11:10 +01:00
{ name : "id" , . . . getTypeByORM ( "int" ) , . . . isIncrementPrimary } ,
{ name : "qualification" , . . . getTypeByORM ( "varchar" ) , isUnique : true } ,
{ name : "description" , . . . getTypeByORM ( "varchar" ) , isNullable : true } ,
2025-01-30 15:58:34 +01:00
] ,
} ) ;
/** member and relations */
export const member_table = new Table ( {
name : "member" ,
columns : [
2025-02-01 13:11:10 +01:00
{ name : "id" , . . . getTypeByORM ( "uuid" ) , . . . isUUIDPrimary } ,
{ name : "salutationId" , . . . getTypeByORM ( "int" ) } ,
{ name : "internalId" , . . . getTypeByORM ( "varchar" , true ) , default : getDefaultByORM ( "null" ) , isUnique : true } ,
{ name : "firstname" , . . . getTypeByORM ( "varchar" ) } ,
{ name : "lastname" , . . . getTypeByORM ( "varchar" ) } ,
{ name : "nameaffix" , . . . getTypeByORM ( "varchar" ) } ,
{ name : "birthdate" , . . . getTypeByORM ( "date" ) } ,
2025-01-30 15:58:34 +01:00
] ,
foreignKeys : [
new TableForeignKey ( {
columnNames : [ "salutationId" ] ,
referencedColumnNames : [ "id" ] ,
referencedTableName : "salutation" ,
onDelete : "RESTRICT" ,
onUpdate : "RESTRICT" ,
} ) ,
] ,
} ) ;
export const membership_table = new Table ( {
name : "membership" ,
columns : [
2025-02-01 13:11:10 +01:00
{ 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" ) } ,
2025-01-30 15:58:34 +01:00
] ,
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 : [
2025-02-01 13:11:10 +01:00
{ 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" ) } ,
2025-01-30 15:58:34 +01:00
] ,
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 : [
2025-02-01 13:11:10 +01:00
{ 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" ) } ,
2025-01-30 15:58:34 +01:00
] ,
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 : [
2025-02-01 13:11:10 +01:00
{ name : "id" , . . . getTypeByORM ( "int" ) , . . . isIncrementPrimary } ,
{ name : "given" , . . . getTypeByORM ( "boolean" ) , default : getDefaultByORM ( "boolean" , false ) } ,
{ name : "note" , . . . getTypeByORM ( "varchar" ) , isNullable : true } ,
{ name : "date" , . . . getTypeByORM ( "date" ) } ,
{ name : "memberId" , . . . getTypeByORM ( "uuid" ) } ,
{ name : "awardId" , . . . getTypeByORM ( "int" ) } ,
2025-01-30 15:58:34 +01:00
] ,
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 : [
2025-02-01 13:11:10 +01:00
{ 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" ) , isNullable : true } ,
{ name : "email" , . . . getTypeByORM ( "varchar" ) , isNullable : true } ,
{ name : "postalCode" , . . . getTypeByORM ( "varchar" ) , default : getDefaultByORM ( "null" ) , isNullable : true } ,
{ name : "city" , . . . getTypeByORM ( "varchar" ) , isNullable : true } ,
{ name : "street" , . . . getTypeByORM ( "varchar" ) , isNullable : true } ,
{ name : "streetNumber" , . . . getTypeByORM ( "int" , true ) } ,
{ name : "streetNumberAddition" , . . . getTypeByORM ( "varchar" ) , isNullable : true } ,
{ name : "memberId" , . . . getTypeByORM ( "uuid" ) } ,
{ name : "typeId" , . . . getTypeByORM ( "int" ) } ,
2025-01-30 15:58:34 +01:00
] ,
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" ,
} ) ,
] ,
} ) ;
/** 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 \` ,
\ ` salutation \` . \` salutation \` AS \` salutation \` ,
2025-02-01 13:11:10 +01:00
TIMESTAMPDIFF ( YEAR , \ ` member \` . \` birthdate \` , CURDATE()) AS \` todayAge \` ,
YEAR ( CURDATE ( ) ) - YEAR ( \ ` member \` . \` birthdate \` ) AS \` ageThisYear \` ,
2025-01-30 15:58:34 +01:00
CONCAT ( '_' , FROM_DAYS ( TIMESTAMPDIFF ( DAY , \ ` member \` . \` birthdate \` , CURDATE()))) AS \` exactAge \`
FROM \ ` member \` \` member \`
LEFT JOIN \ ` salutation \` \` salutation \` ON \` salutation \` . \` id \` = \` member \` . \` salutationId \`
` ,
} ) ;
2025-02-01 13:11:10 +01:00
export const member_view_postgres = 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" ,
"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"
` ,
} ) ;
2025-01-30 15:58:34 +01:00
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 \` ,
2025-02-01 13:11:10 +01:00
SUM ( TIMESTAMPDIFF ( DAY , \ ` memberExecutivePositions \` . \` start \` , COALESCE( \` memberExecutivePositions \` . \` end \` , CURRENT_DATE))) AS \` durationInDays \` ,
CONCAT ( '_' , FROM_DAYS ( SUM ( TIMESTAMPDIFF ( DAY , \ ` memberExecutivePositions \` . \` start \` , COALESCE( \` memberExecutivePositions \` . \` end \` , CURRENT_DATE))))) AS \` durationInYears \`
2025-01-30 15:58:34 +01:00
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 \`
2025-02-01 13:11:10 +01:00
GROUP BY \ ` executivePosition \` . \` id \` , \` member \` . \` id \` , \` salutation \` . \` id \`
` ,
} ) ;
export const member_executive_positions_view_postgres = 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 ( AGE ( COALESCE ( "memberExecutivePositions" . "end" , CURRENT_DATE ) , "memberExecutivePositions" . "start" ) ) AS "durationInYears"
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"
2025-01-30 15:58:34 +01:00
` ,
} ) ;
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 \` ,
2025-02-01 13:11:10 +01:00
SUM ( TIMESTAMPDIFF ( DAY , \ ` memberQualifications \` . \` start \` , COALESCE( \` memberQualifications \` . \` end \` , CURRENT_DATE))) AS \` durationInDays \` ,
CONCAT ( '_' , FROM_DAYS ( SUM ( TIMESTAMPDIFF ( DAY , \ ` memberQualifications \` . \` start \` , COALESCE( \` memberQualifications \` . \` end \` , CURRENT_DATE))))) AS \` durationInYears \`
2025-01-30 15:58:34 +01:00
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 \`
2025-02-01 13:11:10 +01:00
GROUP BY \ ` qualification \` . \` id \` , \` member \` . \` id \` , \` salutation \` . \` id \`
` ,
} ) ;
export const member_qualifications_view_postgres = 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 ( AGE ( COALESCE ( "memberQualifications" . "end" , CURRENT_DATE ) , "memberQualifications" . "start" ) ) AS "durationInYears"
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"
2025-01-30 15:58:34 +01:00
` ,
} ) ;
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 \` ,
2025-02-01 13:11:10 +01:00
SUM ( TIMESTAMPDIFF ( DAY , \ ` membership \` . \` start \` , COALESCE( \` membership \` . \` end \` , CURRENT_DATE))) AS \` durationInDays \` ,
2025-01-30 15:58:34 +01:00
CONCAT ( '_' , FROM_DAYS ( SUM ( TIMESTAMPDIFF ( DAY , \ ` membership \` . \` start \` , COALESCE( \` membership \` . \` end \` , CURRENT_DATE))))) AS \` durationInYears \`
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 \`
2025-02-01 13:11:10 +01:00
GROUP BY \ ` status \` . \` id \` , \` member \` . \` id \` , \` salutation \` . \` id \`
` ,
} ) ;
export const membership_view_postgres = 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 ( AGE ( COALESCE ( "membership" . "end" , CURRENT_DATE ) , "membership" . "start" ) ) AS "durationInYears"
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"
2025-01-30 15:58:34 +01:00
` ,
} ) ;