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

@ -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
`,
});