enhance: add membership total view

This commit is contained in:
Julian Krauser 2025-05-30 15:13:38 +02:00
parent f6a0a61ed8
commit 573f92d098
10 changed files with 219 additions and 3 deletions

View file

@ -195,6 +195,19 @@ export async function getMembershipStatisticsById(req: Request, res: Response):
res.json(MembershipFactory.mapToBaseStatistics(member));
}
/**
* @description get member total statistics by id
* @param req {Request} Express req object
* @param res {Response} Express res object
* @returns {Promise<*>}
*/
export async function getMembershipTotalStatisticsById(req: Request, res: Response): Promise<any> {
const memberId = req.params.memberId;
let member = await MembershipService.getTotalStatisticsById(memberId);
res.json(MembershipFactory.mapToSingleTotalStatistic(member));
}
/**
* @description get membership by member and record
* @param req {Request} Express req object

View file

@ -34,7 +34,7 @@ import { query } from "./entity/configuration/query";
import { memberView } from "./views/memberView";
import { memberExecutivePositionsView } from "./views/memberExecutivePositionView";
import { memberQualificationsView } from "./views/memberQualificationsView";
import { membershipView } from "./views/membershipsView";
import { membershipTotalView, membershipView } from "./views/membershipsView";
import { template } from "./entity/configuration/template";
import { templateUsage } from "./entity/configuration/templateUsage";
import { newsletter } from "./entity/club/newsletter/newsletter";
@ -57,6 +57,7 @@ import { MemberCreatedAt1746006549262 } from "./migrations/1746006549262-memberC
import { UserLoginRoutine1746252454922 } from "./migrations/1746252454922-UserLoginRoutine";
import { SettingsFromEnv_SET1745059495808 } from "./migrations/1745059495808-settingsFromEnv_set";
import { AddDateToNewsletter1748509435932 } from "./migrations/1748509435932-addDateToNewsletter";
import { AddMembershipTotalView1748607842929 } from "./migrations/1748607842929-addMembershipTotalView";
configCheck();
@ -109,6 +110,7 @@ const dataSource = new DataSource({
memberExecutivePositionsView,
memberQualificationsView,
membershipView,
membershipTotalView,
webapi,
webapiPermission,
setting,
@ -125,6 +127,7 @@ const dataSource = new DataSource({
MemberCreatedAt1746006549262,
UserLoginRoutine1746252454922,
AddDateToNewsletter1748509435932,
AddMembershipTotalView1748607842929,
],
migrationsRun: true,
migrationsTransactionMode: "each",

View file

@ -1,9 +1,10 @@
import { membership } from "../../../../entity/club/member/membership";
import {
MembershipStatisticsViewModel,
MembershipTotalStatisticsViewModel,
MembershipViewModel,
} from "../../../../viewmodel/admin/club/member/membership.models";
import { membershipView } from "../../../../views/membershipsView";
import { membershipTotalView, membershipView } from "../../../../views/membershipsView";
import DateMappingHelper from "./dateMappingHelper";
export default abstract class MembershipFactory {
@ -53,6 +54,25 @@ export default abstract class MembershipFactory {
};
}
/**
* @description map view record to MembershipTotalStatisticsViewModel
* @param {membershipTotalView} record
* @returns {MembershipTotalStatisticsViewModel}
*/
public static mapToSingleTotalStatistic(record: membershipTotalView): MembershipTotalStatisticsViewModel {
return {
durationInDays: record.durationInDays,
durationInYears: record.durationInYears,
exactDuration: DateMappingHelper.mapDate(record.exactDuration),
memberId: record.memberId,
memberSalutation: record.memberSalutation,
memberFirstname: record.memberFirstname,
memberLastname: record.memberLastname,
memberNameaffix: record.memberNameaffix,
memberBirthdate: record.memberBirthdate,
};
}
/**
* @description map records to MembershipStatisticsViewModel
* @param {Array<membershipView>} records

View file

@ -22,6 +22,7 @@ export default abstract class DynamicQueryBuilder {
"memberExecutivePositionsView",
"memberQualificationsView",
"membershipView",
"membershipTotalView",
];
public static getTableMeta(tableName: string): TableMeta {

View file

@ -0,0 +1,21 @@
import { MigrationInterface, QueryRunner } from "typeorm";
import { DB_TYPE } from "../env.defaults";
import {
membership_total_view_mysql,
membership_total_view_postgres,
membership_total_view_sqlite,
} from "./baseSchemaTables/member";
export class AddMembershipTotalView1748607842929 implements MigrationInterface {
name = "AddMembershipTotalView1748607842929";
public async up(queryRunner: QueryRunner): Promise<void> {
if (DB_TYPE == "postgres") await queryRunner.createView(membership_total_view_postgres, true);
else if (DB_TYPE == "mysql") await queryRunner.createView(membership_total_view_mysql, true);
else if (DB_TYPE == "sqlite") await queryRunner.createView(membership_total_view_sqlite, true);
}
public async down(queryRunner: QueryRunner): Promise<void> {
await queryRunner.dropView("membership_total_view");
}
}

View file

@ -529,3 +529,76 @@ export const membership_view_sqlite = new View({
GROUP BY status.id, member.id, salutation.id
`,
});
export const membership_total_view_mysql = 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(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\`
LEFT JOIN \`salutation\` \`salutation\` ON \`salutation\`.\`id\`=\`member\`.\`salutationId\`
GROUP BY \`member\`.\`id\`, \`salutation\`.\`id\`
`,
});
export const membership_total_view_postgres = 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"
`,
});
export const membership_total_view_sqlite = 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(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 member.id, salutation.id
`,
});

View file

@ -26,6 +26,7 @@ import {
getMembershipByMemberAndRecord,
getMembershipsByMember,
getMembershipStatisticsById,
getMembershipTotalStatisticsById,
getMemberStatisticsById,
getQualificationByMemberAndRecord,
getQualificationsByMember,
@ -72,6 +73,10 @@ router.get("/:memberId/memberships/statistics", async (req: Request, res: Respon
await getMembershipStatisticsById(req, res);
});
router.get("/:memberId/memberships/totalstatistics", async (req: Request, res: Response) => {
await getMembershipTotalStatisticsById(req, res);
});
router.get("/:memberId/membership/:id", async (req: Request, res: Response) => {
await getMembershipByMemberAndRecord(req, res);
});

View file

@ -2,7 +2,7 @@ import { dataSource } from "../../../data-source";
import { membership } from "../../../entity/club/member/membership";
import DatabaseActionException from "../../../exceptions/databaseActionException";
import InternalException from "../../../exceptions/internalException";
import { membershipView } from "../../../views/membershipsView";
import { membershipTotalView, membershipView } from "../../../views/membershipsView";
export default abstract class MembershipService {
/**
@ -66,4 +66,23 @@ export default abstract class MembershipService {
throw new DatabaseActionException("SELECT", "membershipView", err);
});
}
/**
* @description get membership total statistics by memberId
* @param {string} memberId
* @returns {Promise<Array<membershipTotalView>>}
*/
static async getTotalStatisticsById(memberId: string): Promise<membershipTotalView> {
return await dataSource
.getRepository(membershipTotalView)
.createQueryBuilder("membershipTotalView")
.where("membershipTotalView.memberId = :memberId", { memberId: memberId })
.getOneOrFail()
.then((res) => {
return res;
})
.catch((err) => {
throw new DatabaseActionException("SELECT", "membershipTotalView", err);
});
}
}

View file

@ -20,3 +20,15 @@ export interface MembershipStatisticsViewModel {
memberNameaffix: string;
memberBirthdate: Date;
}
export interface MembershipTotalStatisticsViewModel {
durationInDays: number;
durationInYears: number;
exactDuration: string;
memberId: string;
memberSalutation: string;
memberFirstname: string;
memberLastname: string;
memberNameaffix: string;
memberBirthdate: Date;
}

View file

@ -89,3 +89,52 @@ export class membershipView {
@ViewColumn()
memberBirthdate: Date;
}
@ViewEntity({
expression: (datasource: DataSource) =>
datasource
.getRepository(membership)
.createQueryBuilder("membership")
.select("member.id", "memberId")
.addSelect("member.firstname", "memberFirstname")
.addSelect("member.lastname", "memberLastname")
.addSelect("member.nameaffix", "memberNameaffix")
.addSelect("member.birthdate", "memberBirthdate")
.addSelect("salutation.salutation", "memberSalutation")
.addSelect(durationInDays, "durationInDays")
.addSelect(durationInYears, "durationInYears")
.addSelect(exactDuration, "exactDuration")
.leftJoin("membership.status", "status")
.leftJoin("membership.member", "member")
.leftJoin("member.salutation", "salutation")
.groupBy("status.id")
.addGroupBy("member.id"),
})
export class membershipTotalView {
@ViewColumn()
durationInDays: number;
@ViewColumn()
durationInYears: number;
@ViewColumn()
exactDuration: string;
@ViewColumn()
memberId: string;
@ViewColumn()
memberSalutation: string;
@ViewColumn()
memberFirstname: string;
@ViewColumn()
memberLastname: string;
@ViewColumn()
memberNameaffix: string;
@ViewColumn()
memberBirthdate: Date;
}