From fc01263c4e634835f8094f707859f38a22850564 Mon Sep 17 00:00:00 2001 From: Julian Krauser Date: Sat, 1 Feb 2025 18:09:58 +0100 Subject: [PATCH] enhance views to display exact year, month, day values sqlite displays negative days and months --- README.md | 2 +- src/factory/admin/club/member/member.ts | 1 + src/factory/admin/club/member/membership.ts | 1 + src/migrations/1738166167472-CreateSchema.ts | 24 ++- src/migrations/baseSchemaTables/member.ts | 165 ++++++++++++++++-- .../admin/club/member/member.models.ts | 1 + .../admin/club/member/membership.models.ts | 3 +- src/views/memberExecutivePositionView.ts | 50 ++++-- src/views/memberQualificationsView.ts | 50 ++++-- src/views/memberView.ts | 58 ++++-- src/views/membershipsView.ts | 50 ++++-- 11 files changed, 324 insertions(+), 81 deletions(-) diff --git a/README.md b/README.md index 432cc37..c697570 100644 --- a/README.md +++ b/README.md @@ -82,7 +82,7 @@ networks: ff_internal: ``` -Die Verwendung von postgres wird aufgrund des Verhaltens bei Struktur-Update-Fehlern und genauerer Datum-Berechnungen empfohlen. +Die Verwendung von postgres wird aufgrund des Verhaltens bei Datenbank-Update-Fehlern empfohlen. Die Verwendung von SQLite wird nur für die Entwicklung oder lokale Tests empfohlen. diff --git a/src/factory/admin/club/member/member.ts b/src/factory/admin/club/member/member.ts index e934025..95a46cb 100644 --- a/src/factory/admin/club/member/member.ts +++ b/src/factory/admin/club/member/member.ts @@ -51,6 +51,7 @@ export default abstract class MemberFactory { public static mapToMemberStatistic(record: memberView): MemberStatisticsViewModel { return { id: record.id, + internalId: record.internalId, salutation: record.salutation, firstname: record.firstname, lastname: record.lastname, diff --git a/src/factory/admin/club/member/membership.ts b/src/factory/admin/club/member/membership.ts index 42980ab..cbc171a 100644 --- a/src/factory/admin/club/member/membership.ts +++ b/src/factory/admin/club/member/membership.ts @@ -40,6 +40,7 @@ export default abstract class MembershipFactory { return { durationInDays: record.durationInDays, durationInYears: record.durationInYears, + exactDuration: record.exactDuration, status: record.status, statusId: record.statusId, memberId: record.memberId, diff --git a/src/migrations/1738166167472-CreateSchema.ts b/src/migrations/1738166167472-CreateSchema.ts index f5995b7..70a6c97 100644 --- a/src/migrations/1738166167472-CreateSchema.ts +++ b/src/migrations/1738166167472-CreateSchema.ts @@ -19,18 +19,22 @@ import { member_awards_table, member_communication_table, member_executive_positions_table, - member_executive_positions_view, + member_executive_positions_view_mysql, member_executive_positions_view_postgres, + member_executive_positions_view_sqlite, member_qualifications_table, - member_qualifications_view, + member_qualifications_view_mysql, member_qualifications_view_postgres, + member_qualifications_view_sqlite, member_table, - member_view, + member_view_mysql, member_view_postgres, + member_view_sqlite, membership_status_table, membership_table, - membership_view, + membership_view_mysql, membership_view_postgres, + membership_view_sqlite, qualification_table, salutation_table, } from "./baseSchemaTables/member"; @@ -81,13 +85,17 @@ export class CreateSchema1738166167472 implements MigrationInterface { await queryRunner.createTable(member_qualifications_table, true, true, true); if (DB_TYPE == "postgres") await queryRunner.createView(member_view_postgres, true); - else await queryRunner.createView(member_view, true); + else if (DB_TYPE == "mysql") await queryRunner.createView(member_view_mysql, true); + else if (DB_TYPE == "sqlite") await queryRunner.createView(member_view_sqlite, true); if (DB_TYPE == "postgres") await queryRunner.createView(membership_view_postgres, true); - else await queryRunner.createView(membership_view, true); + else if (DB_TYPE == "mysql") await queryRunner.createView(membership_view_mysql, true); + else if (DB_TYPE == "sqlite") await queryRunner.createView(membership_view_sqlite, true); if (DB_TYPE == "postgres") await queryRunner.createView(member_qualifications_view_postgres, true); - else await queryRunner.createView(member_qualifications_view, true); + else if (DB_TYPE == "mysql") await queryRunner.createView(member_qualifications_view_mysql, true); + else if (DB_TYPE == "sqlite") await queryRunner.createView(member_qualifications_view_sqlite, true); if (DB_TYPE == "postgres") await queryRunner.createView(member_executive_positions_view_postgres, true); - else await queryRunner.createView(member_executive_positions_view, true); + else if (DB_TYPE == "mysql") await queryRunner.createView(member_executive_positions_view_mysql, true); + else if (DB_TYPE == "sqlite") await queryRunner.createView(member_executive_positions_view_sqlite, true); await queryRunner.createTable(query_table, true, true, true); await queryRunner.createTable(template_table, true, true, true); diff --git a/src/migrations/baseSchemaTables/member.ts b/src/migrations/baseSchemaTables/member.ts index c2657cb..422f3cd 100644 --- a/src/migrations/baseSchemaTables/member.ts +++ b/src/migrations/baseSchemaTables/member.ts @@ -223,11 +223,12 @@ export const member_communication_table = new Table({ }); /** views */ -export const member_view = new View({ +export const member_view_mysql = new View({ name: "member_view", expression: ` SELECT \`member\`.\`id\` AS \`id\`, + \`member\`.\`internalId\` AS \`internalId\`, \`member\`.\`firstname\` AS \`firstname\`, \`member\`.\`lastname\` AS \`lastname\`, \`member\`.\`nameaffix\` AS \`nameaffix\`, @@ -235,7 +236,17 @@ export const member_view = new View({ \`salutation\`.\`salutation\` AS \`salutation\`, TIMESTAMPDIFF(YEAR, \`member\`.\`birthdate\`, CURDATE()) AS \`todayAge\`, YEAR(CURDATE()) - YEAR(\`member\`.\`birthdate\`) AS \`ageThisYear\`, - CONCAT('_', FROM_DAYS(TIMESTAMPDIFF(DAY, \`member\`.\`birthdate\`, CURDATE()))) AS \`exactAge\` + CONCAT( + TIMESTAMPDIFF(YEAR, \`member\`.\`birthdate\`, CURDATE()), ' years ', + TIMESTAMPDIFF(MONTH, \`member\`.\`birthdate\`, CURDATE()) % 12, ' months ', + TIMESTAMPDIFF(DAY, + DATE_ADD( + \`member\`.\`birthdate\`, + INTERVAL TIMESTAMPDIFF(MONTH, \`member\`.\`birthdate\`, CURDATE()) MONTH + ), + CURDATE() + ), ' days' + ) AS \`exactAge\` FROM \`member\` \`member\` LEFT JOIN \`salutation\` \`salutation\` ON \`salutation\`.\`id\`=\`member\`.\`salutationId\` `, @@ -246,6 +257,7 @@ export const member_view_postgres = new View({ expression: ` SELECT "member"."id" AS "id", + "member"."internalId" AS "internalId", "member"."firstname" AS "firstname", "member"."lastname" AS "lastname", "member"."nameaffix" AS "nameaffix", @@ -259,7 +271,29 @@ export const member_view_postgres = new View({ `, }); -export const member_executive_positions_view = new View({ +export const member_view_sqlite = new View({ + name: "member_view", + expression: ` + SELECT + member.id AS id, + member.internalId AS internalId, + member.firstname AS firstname, + member.lastname AS lastname, + member.nameaffix AS nameaffix, + member.birthdate AS birthdate, + salutation.salutation AS salutation, + (strftime('%Y', 'now') - strftime('%Y', member.birthdate) - (strftime('%m-%d', 'now') < strftime('%m-%d', member.birthdate))) AS todayAge, + FLOOR(strftime('%Y', 'now') - strftime('%Y', member.birthdate)) AS ageThisYear, + (strftime('%Y', 'now') - strftime('%Y', member.birthdate)) || ' years ' || + (strftime('%m', 'now') - strftime('%m', member.birthdate)) || ' months ' || + (strftime('%d', 'now') - strftime('%d', member.birthdate)) || ' days' + AS exactAge + FROM member member + LEFT JOIN salutation salutation ON salutation.id=member.salutationId + `, +}); + +export const member_executive_positions_view_mysql = new View({ name: "member_executive_positions_view", expression: ` SELECT @@ -271,8 +305,16 @@ export const member_executive_positions_view = new View({ \`member\`.\`nameaffix\` AS \`memberNameaffix\`, \`member\`.\`birthdate\` AS \`memberBirthdate\`, \`salutation\`.\`salutation\` AS \`memberSalutation\`, - 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\` + SUM(DATEDIFF(COALESCE(\`memberExecutivePositions\`.\`end\`, CURDATE()), \`memberExecutivePositions\`.\`start\`)) AS \`durationInDays\`, + SUM(TIMESTAMPDIFF(YEAR, \`memberExecutivePositions\`.\`start\`, COALESCE(\`memberExecutivePositions\`.\`end\`, CURDATE()))) AS \`durationInYears\`, + CONCAT( + SUM(FLOOR(TIMESTAMPDIFF(DAY, \`memberExecutivePositions\`.\`start\`, COALESCE(\`memberExecutivePositions\`.\`end\`, CURDATE())) / 365.25)), + ' years ', + SUM(FLOOR(MOD(TIMESTAMPDIFF(MONTH, \`memberExecutivePositions\`.\`start\`, COALESCE(\`memberExecutivePositions\`.\`end\`, CURDATE())), 12))), + ' months ', + SUM(FLOOR(MOD(TIMESTAMPDIFF(DAY, \`memberExecutivePositions\`.\`start\`, COALESCE(\`memberExecutivePositions\`.\`end\`, CURDATE())), 30))), + ' days' + ) 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\` @@ -294,7 +336,8 @@ export const member_executive_positions_view_postgres = new View({ "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" + SUM(EXTRACT(YEAR FROM CURRENT_DATE) - EXTRACT(YEAR FROM member.birthdate)) 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" @@ -303,7 +346,33 @@ export const member_executive_positions_view_postgres = new View({ `, }); -export const member_qualifications_view = new View({ +export const member_executive_positions_view_sqlite = 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(JULIANDAY(COALESCE(memberExecutivePositions.end, DATE('now'))) - JULIANDAY(memberExecutivePositions.start)) AS durationInDays, + SUM(FLOOR((JULIANDAY(COALESCE(memberExecutivePositions.end, DATE('now'))) - JULIANDAY(memberExecutivePositions.start)) / 365.25)) AS durationInYears, + SUM((strftime('%Y', COALESCE(memberExecutivePositions.end, DATE('now'))) - strftime('%Y', memberExecutivePositions.start))) || ' years ' || + SUM((strftime('%m', COALESCE(memberExecutivePositions.end, DATE('now'))) - strftime('%m', memberExecutivePositions.start))) || ' months ' || + SUM((strftime('%d', COALESCE(memberExecutivePositions.end, DATE('now'))) - strftime('%d', memberExecutivePositions.start))) || ' days' + 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 + `, +}); + +export const member_qualifications_view_mysql = new View({ name: "member_qualifications_view", expression: ` SELECT @@ -314,9 +383,17 @@ export const member_qualifications_view = new View({ \`member\`.\`lastname\` AS \`memberLastname\`, \`member\`.\`nameaffix\` AS \`memberNameaffix\`, \`member\`.\`birthdate\` AS \`memberBirthdate\`, - \`salutation\`.\`salutation\` AS \`memberSalutation\`, - 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\` + \`salutation\`.\`salutation\` AS \`memberSalutation\`, + SUM(DATEDIFF(COALESCE(\`memberQualifications\`.\`end\`, CURDATE()), \`memberQualifications\`.\`start\`)) AS \`durationInDays\`, + SUM(TIMESTAMPDIFF(YEAR, \`memberQualifications\`.\`start\`, COALESCE(\`memberQualifications\`.\`end\`, CURDATE()))) AS \`durationInYears\`, + CONCAT( + SUM(FLOOR(TIMESTAMPDIFF(DAY, \`memberQualifications\`.\`start\`, COALESCE(\`memberQualifications\`.\`end\`, CURDATE())) / 365.25)), + ' years ', + SUM(FLOOR(MOD(TIMESTAMPDIFF(MONTH, \`memberQualifications\`.\`start\`, COALESCE(\`memberQualifications\`.\`end\`, CURDATE())), 12))), + ' months ', + SUM(FLOOR(MOD(TIMESTAMPDIFF(DAY, \`memberQualifications\`.\`start\`, COALESCE(\`memberQualifications\`.\`end\`, CURDATE())), 30))), + ' days' + ) AS \`exactDuration\` FROM \`member_qualifications\` \`memberQualifications\` LEFT JOIN \`qualification\` \`qualification\` ON \`qualification\`.\`id\`=\`memberQualifications\`.\`qualificationId\` LEFT JOIN \`member\` \`member\` ON \`member\`.\`id\`=\`memberQualifications\`.\`memberId\` @@ -347,7 +424,33 @@ export const member_qualifications_view_postgres = new View({ `, }); -export const membership_view = new View({ +export const member_qualifications_view_sqlite = 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(JULIANDAY(COALESCE(memberQualifications.end, DATE('now'))) - JULIANDAY(memberQualifications.start)) AS durationInDays, + SUM(FLOOR((JULIANDAY(COALESCE(memberQualifications.end, DATE('now'))) - JULIANDAY(memberQualifications.start)) / 365.25)) AS durationInYears, + SUM((strftime('%Y', COALESCE(memberQualifications.end, DATE('now'))) - strftime('%Y', memberQualifications.start))) || ' years ' || + SUM((strftime('%m', COALESCE(memberQualifications.end, DATE('now'))) - strftime('%m', memberQualifications.start))) || ' months ' || + SUM((strftime('%d', COALESCE(memberQualifications.end, DATE('now'))) - strftime('%d', memberQualifications.start))) || ' days' + 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 + `, +}); + +export const membership_view_mysql = new View({ name: "membership_view", expression: ` SELECT @@ -358,9 +461,17 @@ export const membership_view = new View({ \`member\`.\`lastname\` AS \`memberLastname\`, \`member\`.\`nameaffix\` AS \`memberNameaffix\`, \`member\`.\`birthdate\` AS \`memberBirthdate\`, - \`salutation\`.\`salutation\` AS \`memberSalutation\`, - SUM(TIMESTAMPDIFF(DAY, \`membership\`.\`start\`, COALESCE(\`membership\`.\`end\`, CURRENT_DATE))) AS \`durationInDays\`, - CONCAT('_', FROM_DAYS(SUM(TIMESTAMPDIFF(DAY, \`membership\`.\`start\`, COALESCE(\`membership\`.\`end\`, CURRENT_DATE))))) AS \`durationInYears\` + \`salutation\`.\`salutation\` AS \`memberSalutation\`, + SUM(DATEDIFF(COALESCE(\`membership\`.\`end\`, CURDATE()), \`membership\`.\`start\`)) AS \`durationInDays\`, + SUM(TIMESTAMPDIFF(YEAR, \`membership\`.\`start\`, COALESCE(\`membership\`.\`end\`, CURDATE()))) AS \`durationInYears\`, + CONCAT( + SUM(FLOOR(TIMESTAMPDIFF(DAY, \`membership\`.\`start\`, COALESCE(\`membership\`.\`end\`, CURDATE())) / 365.25)), + ' years ', + SUM(FLOOR(MOD(TIMESTAMPDIFF(MONTH, \`membership\`.\`start\`, COALESCE(\`membership\`.\`end\`, CURDATE())), 12))), + ' months ', + SUM(FLOOR(MOD(TIMESTAMPDIFF(DAY, \`membership\`.\`start\`, COALESCE(\`membership\`.\`end\`, CURDATE())), 30))), + ' days' + ) AS \`exactDuration\` FROM \`membership\` \`membership\` LEFT JOIN \`membership_status\` \`status\` ON \`status\`.\`id\`=\`membership\`.\`statusId\` LEFT JOIN \`member\` \`member\` ON \`member\`.\`id\`=\`membership\`.\`memberId\` @@ -390,3 +501,29 @@ export const membership_view_postgres = new View({ GROUP BY "status"."id","member"."id", "salutation"."id" `, }); + +export const membership_view_sqlite = 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(JULIANDAY(COALESCE(membership.end, DATE('now'))) - JULIANDAY(membership.start)) AS durationInDays, + SUM(FLOOR((JULIANDAY(COALESCE(membership.end, DATE('now'))) - JULIANDAY(membership.start)) / 365.25)) AS durationInYears, + SUM((strftime('%Y', COALESCE(membership.end, DATE('now'))) - strftime('%Y', membership.start))) || ' years ' || + SUM((strftime('%m', COALESCE(membership.end, DATE('now'))) - strftime('%m', membership.start))) || ' months ' || + SUM((strftime('%d', COALESCE(membership.end, DATE('now'))) - strftime('%d', membership.start))) || ' days' + 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 + `, +}); diff --git a/src/viewmodel/admin/club/member/member.models.ts b/src/viewmodel/admin/club/member/member.models.ts index 466a6f7..69f1bdf 100644 --- a/src/viewmodel/admin/club/member/member.models.ts +++ b/src/viewmodel/admin/club/member/member.models.ts @@ -19,6 +19,7 @@ export interface MemberViewModel { export interface MemberStatisticsViewModel { id: string; + internalId: string; salutation: string; firstname: string; lastname: string; diff --git a/src/viewmodel/admin/club/member/membership.models.ts b/src/viewmodel/admin/club/member/membership.models.ts index 6b53086..ace02ea 100644 --- a/src/viewmodel/admin/club/member/membership.models.ts +++ b/src/viewmodel/admin/club/member/membership.models.ts @@ -9,7 +9,8 @@ export interface MembershipViewModel { export interface MembershipStatisticsViewModel { durationInDays: number; - durationInYears: string; + durationInYears: number; + exactDuration: string; status: string; statusId: number; memberId: string; diff --git a/src/views/memberExecutivePositionView.ts b/src/views/memberExecutivePositionView.ts index 610fe34..f82e35c 100644 --- a/src/views/memberExecutivePositionView.ts +++ b/src/views/memberExecutivePositionView.ts @@ -2,6 +2,36 @@ import { DataSource, ViewColumn, ViewEntity } from "typeorm"; import { memberExecutivePositions } from "../entity/club/member/memberExecutivePositions"; import { DB_TYPE } from "../env.defaults"; +let durationInDays: string; +let durationInYears: string; +let exactDuration: string; +if (DB_TYPE == "postgres") { + durationInDays = `SUM(COALESCE("memberExecutivePositions"."end", CURRENT_DATE) - "memberExecutivePositions"."start")`; + durationInYears = `SUM(EXTRACT(YEAR FROM CURRENT_DATE) - EXTRACT(YEAR FROM member.birthdate))`; + exactDuration = `SUM(AGE(COALESCE("memberExecutivePositions"."end", CURRENT_DATE), "memberExecutivePositions"."start"))`; +} else if (DB_TYPE == "mysql") { + durationInDays = `SUM(DATEDIFF(COALESCE(memberExecutivePositions.end, CURDATE()), memberExecutivePositions.start))`; + durationInYears = `SUM(TIMESTAMPDIFF(YEAR, memberExecutivePositions.start, COALESCE(memberExecutivePositions.end, CURDATE())))`; + exactDuration = ` + CONCAT( + SUM(FLOOR(TIMESTAMPDIFF(DAY, memberExecutivePositions.start, COALESCE(memberExecutivePositions.end, CURDATE())) / 365.25)), + ' years ', + SUM(FLOOR(MOD(TIMESTAMPDIFF(MONTH, memberExecutivePositions.start, COALESCE(memberExecutivePositions.end, CURDATE())), 12))), + ' months ', + SUM(FLOOR(MOD(TIMESTAMPDIFF(DAY, memberExecutivePositions.start, COALESCE(memberExecutivePositions.end, CURDATE())), 30))), + ' days' + ) + `; +} else if (DB_TYPE == "sqlite") { + durationInDays = `SUM(JULIANDAY(COALESCE(memberExecutivePositions.end, DATE('now'))) - JULIANDAY(memberExecutivePositions.start))`; + durationInYears = `SUM(FLOOR((JULIANDAY(COALESCE(memberExecutivePositions.end, DATE('now'))) - JULIANDAY(memberExecutivePositions.start)) / 365.25))`; + exactDuration = ` + SUM((strftime('%Y', COALESCE(memberExecutivePositions.end, DATE('now'))) - strftime('%Y', memberExecutivePositions.start))) || ' years ' || + SUM((strftime('%m', COALESCE(memberExecutivePositions.end, DATE('now'))) - strftime('%m', memberExecutivePositions.start))) || ' months ' || + SUM((strftime('%d', COALESCE(memberExecutivePositions.end, DATE('now'))) - strftime('%d', memberExecutivePositions.start))) || ' days' + `; +} + @ViewEntity({ expression: (datasource: DataSource) => datasource @@ -15,18 +45,9 @@ import { DB_TYPE } from "../env.defaults"; .addSelect("member.nameaffix", "memberNameaffix") .addSelect("member.birthdate", "memberBirthdate") .addSelect("salutation.salutation", "memberSalutation") - .addSelect( - DB_TYPE == "postgres" - ? `SUM(COALESCE("memberExecutivePositions"."end", CURRENT_DATE) - "memberExecutivePositions"."start")` - : "SUM(TIMESTAMPDIFF(DAY, memberExecutivePositions.start, COALESCE(memberExecutivePositions.end, CURRENT_DATE)))", - "durationInDays" - ) - .addSelect( - DB_TYPE == "postgres" - ? `SUM(AGE(COALESCE("memberExecutivePositions"."end", CURRENT_DATE), "memberExecutivePositions"."start"))` - : "CONCAT('_', FROM_DAYS(SUM(TIMESTAMPDIFF(DAY, memberExecutivePositions.start, COALESCE(memberExecutivePositions.end, CURRENT_DATE)))))", - "durationInYears" - ) + .addSelect(durationInDays, "durationInDays") + .addSelect(durationInYears, "durationInYears") + .addSelect(exactDuration, "exactDuration") .leftJoin("memberExecutivePositions.executivePosition", "executivePosition") .leftJoin("memberExecutivePositions.member", "member") .leftJoin("member.salutation", "salutation") @@ -39,7 +60,10 @@ export class memberExecutivePositionsView { durationInDays: number; @ViewColumn() - durationInYears: string; + durationInYears: number; + + @ViewColumn() + exactDuration: string; @ViewColumn() position: string; diff --git a/src/views/memberQualificationsView.ts b/src/views/memberQualificationsView.ts index 1e6dd55..45d6089 100644 --- a/src/views/memberQualificationsView.ts +++ b/src/views/memberQualificationsView.ts @@ -2,6 +2,36 @@ import { DataSource, ViewColumn, ViewEntity } from "typeorm"; import { memberQualifications } from "../entity/club/member/memberQualifications"; import { DB_TYPE } from "../env.defaults"; +let durationInDays: string; +let durationInYears: string; +let exactDuration: string; +if (DB_TYPE == "postgres") { + durationInDays = `SUM(COALESCE("memberQualifications"."end", CURRENT_DATE) - "memberQualifications"."start") `; + durationInYears = `SUM(EXTRACT(YEAR FROM CURRENT_DATE) - EXTRACT(YEAR FROM member.birthdate))`; + exactDuration = `SUM(AGE(COALESCE("memberQualifications"."end", CURRENT_DATE), "memberQualifications"."start"))`; +} else if (DB_TYPE == "mysql") { + durationInDays = `SUM(DATEDIFF(COALESCE(memberQualifications.end, CURDATE()), memberQualifications.start))`; + durationInYears = `SUM(TIMESTAMPDIFF(YEAR, memberQualifications.start, COALESCE(memberQualifications.end, CURDATE())))`; + exactDuration = ` + CONCAT( + SUM(FLOOR(TIMESTAMPDIFF(DAY, memberQualifications.start, COALESCE(memberQualifications.end, CURDATE())) / 365.25)), + ' years ', + SUM(FLOOR(MOD(TIMESTAMPDIFF(MONTH, memberQualifications.start, COALESCE(memberQualifications.end, CURDATE())), 12))), + ' months ', + SUM(FLOOR(MOD(TIMESTAMPDIFF(DAY, memberQualifications.start, COALESCE(memberQualifications.end, CURDATE())), 30))), + ' days' + ) + `; +} else if (DB_TYPE == "sqlite") { + durationInDays = `SUM(JULIANDAY(COALESCE(memberQualifications.end, DATE('now'))) - JULIANDAY(memberQualifications.start))`; + durationInYears = `SUM(FLOOR((JULIANDAY(COALESCE(memberQualifications.end, DATE('now'))) - JULIANDAY(memberQualifications.start)) / 365.25))`; + exactDuration = ` + SUM((strftime('%Y', COALESCE(memberQualifications.end, DATE('now'))) - strftime('%Y', memberQualifications.start))) || ' years ' || + SUM((strftime('%m', COALESCE(memberQualifications.end, DATE('now'))) - strftime('%m', memberQualifications.start))) || ' months ' || + SUM((strftime('%d', COALESCE(memberQualifications.end, DATE('now'))) - strftime('%d', memberQualifications.start))) || ' days' + `; +} + @ViewEntity({ expression: (datasource: DataSource) => datasource @@ -15,18 +45,9 @@ import { DB_TYPE } from "../env.defaults"; .addSelect("member.nameaffix", "memberNameaffix") .addSelect("member.birthdate", "memberBirthdate") .addSelect("salutation.salutation", "memberSalutation") - .addSelect( - DB_TYPE == "postgres" - ? `SUM(COALESCE("memberQualifications"."end", CURRENT_DATE) - "memberQualifications"."start")` - : "SUM(TIMESTAMPDIFF(DAY, memberQualifications.start, COALESCE(memberQualifications.end, CURRENT_DATE)))", - "durationInDays" - ) - .addSelect( - DB_TYPE == "postgres" - ? `SUM(AGE(COALESCE("memberQualifications"."end", CURRENT_DATE), "memberQualifications"."start"))` - : "CONCAT('_', FROM_DAYS(SUM(TIMESTAMPDIFF(DAY, memberQualifications.start, COALESCE(memberQualifications.end, CURRENT_DATE)))))", - "durationInYears" - ) + .addSelect(durationInDays, "durationInDays") + .addSelect(durationInYears, "durationInYears") + .addSelect(exactDuration, "exactDuration") .leftJoin("memberQualifications.qualification", "qualification") .leftJoin("memberQualifications.member", "member") .leftJoin("member.salutation", "salutation") @@ -39,7 +60,10 @@ export class memberQualificationsView { durationInDays: number; @ViewColumn() - durationInYears: string; + durationInYears: number; + + @ViewColumn() + exactDuration: string; @ViewColumn() qualification: string; diff --git a/src/views/memberView.ts b/src/views/memberView.ts index 11de1e8..194bade 100644 --- a/src/views/memberView.ts +++ b/src/views/memberView.ts @@ -2,35 +2,54 @@ import { DataSource, ViewColumn, ViewEntity } from "typeorm"; import { member } from "../entity/club/member/member"; import { DB_TYPE } from "../env.defaults"; +let todayAge: string; +let ageThisYear: string; +let exactAge: string; +if (DB_TYPE == "postgres") { + todayAge = `DATE_PART('year', AGE(CURRENT_DATE, member.birthdate))`; + ageThisYear = `EXTRACT(YEAR FROM CURRENT_DATE) - EXTRACT(YEAR FROM member.birthdate)`; + exactAge = `AGE(CURRENT_DATE, member.birthdate)`; +} else if (DB_TYPE == "mysql") { + todayAge = `TIMESTAMPDIFF(YEAR, member.birthdate, CURDATE()) AS todayAge`; + ageThisYear = `YEAR(CURDATE()) - YEAR(member.birthdate) AS ageThisYear`; + exactAge = ` + CONCAT( + TIMESTAMPDIFF(YEAR, member.birthdate, CURDATE()), ' years ', + TIMESTAMPDIFF(MONTH, member.birthdate, CURDATE()) % 12, ' months ', + TIMESTAMPDIFF(DAY, + DATE_ADD( + member.birthdate, + INTERVAL TIMESTAMPDIFF(MONTH, member.birthdate, CURDATE()) MONTH + ), + CURDATE() + ), ' days' + ) + `; +} else if (DB_TYPE == "sqlite") { + todayAge = `(strftime('%Y', 'now') - strftime('%Y', member.birthdate) - (strftime('%m-%d', 'now') < strftime('%m-%d', member.birthdate)))`; + ageThisYear = `strftime('%Y', 'now') - strftime('%Y', member.birthdate)`; + exactAge = ` + (strftime('%Y', 'now') - strftime('%Y', member.birthdate)) || ' years ' || + (strftime('%m', 'now') - strftime('%m', member.birthdate)) || ' months ' || + (strftime('%d', 'now') - strftime('%d', member.birthdate)) || ' days' + `; +} + @ViewEntity({ expression: (datasource: DataSource) => datasource .getRepository(member) .createQueryBuilder("member") .select("member.id", "id") + .select("member.internalId", "internalId") .addSelect("member.firstname", "firstname") .addSelect("member.lastname", "lastname") .addSelect("member.nameaffix", "nameaffix") .addSelect("member.birthdate", "birthdate") .addSelect("salutation.salutation", "salutation") - .addSelect( - DB_TYPE == "postgres" - ? `DATE_PART('year', AGE(CURRENT_DATE, member.birthdate))` - : "TIMESTAMPDIFF(YEAR, member.birthdate, CURDATE())", - "todayAge" - ) - .addSelect( - DB_TYPE == "postgres" - ? `EXTRACT(YEAR FROM CURRENT_DATE) - EXTRACT(YEAR FROM member.birthdate)` - : "YEAR(CURDATE()) - YEAR(member.birthdate)", - "ageThisYear" - ) - .addSelect( - DB_TYPE == "postgres" - ? `AGE(CURRENT_DATE, member.birthdate)` - : "CONCAT('_', FROM_DAYS(TIMESTAMPDIFF(DAY, member.birthdate, CURDATE())))", - "exactAge" - ) + .addSelect(todayAge, "todayAge") + .addSelect(ageThisYear, "ageThisYear") + .addSelect(exactAge, "exactAge") .leftJoin("member.salutation", "salutation"), }) export class memberView { @@ -40,6 +59,9 @@ export class memberView { @ViewColumn() salutation: string; + @ViewColumn() + internalId: string; + @ViewColumn() firstname: string; diff --git a/src/views/membershipsView.ts b/src/views/membershipsView.ts index 5a614de..68d1927 100644 --- a/src/views/membershipsView.ts +++ b/src/views/membershipsView.ts @@ -2,6 +2,36 @@ import { DataSource, ViewColumn, ViewEntity } from "typeorm"; import { membership } from "../entity/club/member/membership"; import { DB_TYPE } from "../env.defaults"; +let durationInDays: string; +let durationInYears: string; +let exactDuration: string; +if (DB_TYPE == "postgres") { + durationInDays = `SUM(COALESCE("membership"."end", CURRENT_DATE) - "membership"."start") `; + durationInYears = `SUM(EXTRACT(YEAR FROM CURRENT_DATE) - EXTRACT(YEAR FROM member.birthdate))`; + exactDuration = `SUM(AGE(COALESCE("membership"."end", CURRENT_DATE), "membership"."start"))`; +} else if (DB_TYPE == "mysql") { + durationInDays = `SUM(DATEDIFF(COALESCE(membership.end, CURDATE()), membership.start))`; + durationInYears = `SUM(TIMESTAMPDIFF(YEAR, membership.start, COALESCE(membership.end, CURDATE())))`; + exactDuration = ` + CONCAT( + SUM(FLOOR(TIMESTAMPDIFF(DAY, membership.start, COALESCE(membership.end, CURDATE())) / 365.25)), + ' years ', + SUM(FLOOR(MOD(TIMESTAMPDIFF(MONTH, membership.start, COALESCE(membership.end, CURDATE())), 12))), + ' months ', + SUM(FLOOR(MOD(TIMESTAMPDIFF(DAY, membership.start, COALESCE(membership.end, CURDATE())), 30))), + ' days' + ) + `; +} else if (DB_TYPE == "sqlite") { + durationInDays = `SUM(JULIANDAY(COALESCE(membership.end, DATE('now'))) - JULIANDAY(membership.start))`; + durationInYears = `SUM(FLOOR((JULIANDAY(COALESCE(membership.end, DATE('now'))) - JULIANDAY(membership.start)) / 365.25))`; + exactDuration = ` + SUM((strftime('%Y', COALESCE(membership.end, DATE('now'))) - strftime('%Y', membership.start))) || ' years ' || + SUM((strftime('%m', COALESCE(membership.end, DATE('now'))) - strftime('%m', membership.start))) || ' months ' || + SUM((strftime('%d', COALESCE(membership.end, DATE('now'))) - strftime('%d', membership.start))) || ' days' + `; +} + @ViewEntity({ expression: (datasource: DataSource) => datasource @@ -15,18 +45,9 @@ import { DB_TYPE } from "../env.defaults"; .addSelect("member.nameaffix", "memberNameaffix") .addSelect("member.birthdate", "memberBirthdate") .addSelect("salutation.salutation", "memberSalutation") - .addSelect( - DB_TYPE == "postgres" - ? `SUM(COALESCE("membership"."end", CURRENT_DATE) - "membership"."start") ` - : "SUM(TIMESTAMPDIFF(DAY, membership.start, COALESCE(membership.end, CURRENT_DATE)))", - "durationInDays" - ) - .addSelect( - DB_TYPE == "postgres" - ? `SUM(AGE(COALESCE("membership"."end", CURRENT_DATE), "membership"."start"))` - : "CONCAT('_', FROM_DAYS(SUM(TIMESTAMPDIFF(DAY, membership.start, COALESCE(membership.end, CURRENT_DATE)))))", - "durationInYears" - ) + .addSelect(durationInDays, "durationInDays") + .addSelect(durationInYears, "durationInYears") + .addSelect(exactDuration, "exactDuration") .leftJoin("membership.status", "status") .leftJoin("membership.member", "member") .leftJoin("member.salutation", "salutation") @@ -39,7 +60,10 @@ export class membershipView { durationInDays: number; @ViewColumn() - durationInYears: string; + durationInYears: number; + + @ViewColumn() + exactDuration: string; @ViewColumn() status: string;