Skip to content

Commit

Permalink
Merge pull request #85 from jharrell/add-typedsql
Browse files Browse the repository at this point in the history
add TypedSQL feature for Prisma
  • Loading branch information
driaug authored Sep 13, 2024
2 parents 2130811 + d2d5440 commit 3a82222
Show file tree
Hide file tree
Showing 7 changed files with 9,992 additions and 13,468 deletions.
10 changes: 5 additions & 5 deletions package.json
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
{
"name": "plunk",
"version": "1.0.5",
"version": "1.0.6",
"private": true,
"license": "agpl-3.0",
"workspaces": {
Expand All @@ -14,11 +14,11 @@
"devDependencies": {
"@biomejs/biome": "^1.8.3",
"lerna": "^8.1.6",
"prisma": "^5.17.0",
"prisma": "^5.19.1",
"rimraf": "^5.0.9"
},
"dependencies": {
"@prisma/client": "^5.17.0"
"@prisma/client": "^5.19.1"
},
"scripts": {
"dev:api": "yarn workspace @plunk/api dev",
Expand All @@ -31,8 +31,8 @@
"preinstall": "node tools/preinstall.js",
"migrate": "prisma migrate dev",
"migrate:deploy": "prisma migrate deploy",
"generate": "prisma generate",
"generate": "prisma generate --sql",
"services:up": "docker compose -f docker-compose.dev.yml up -d",
"services:down": "docker compose -f docker-compose.dev.yml down"
}
}
}
9 changes: 7 additions & 2 deletions packages/api/src/database/prisma.ts
Original file line number Diff line number Diff line change
@@ -1,4 +1,5 @@
import {PrismaClient} from '@prisma/client';
import { PrismaClient } from '@prisma/client';
import { contacts, rawActionClicks } from '@prisma/client/sql';
import signale from 'signale';

let prisma: PrismaClient;
Expand All @@ -8,4 +9,8 @@ try {
} catch (error) {
signale.error('Failed to initialize Prisma: ', error);
}
export {prisma};
const sql = {
contacts,
rawActionClicks
}
export { prisma, sql };
54 changes: 9 additions & 45 deletions packages/api/src/services/ProjectService.ts
Original file line number Diff line number Diff line change
@@ -1,5 +1,5 @@
import dayjs from "dayjs";
import { prisma } from "../database/prisma";
import { prisma, sql } from "../database/prisma";
import { Keys } from "./keys";
import { wrapRedis } from "./redis";

Expand Down Expand Up @@ -300,63 +300,27 @@ export class ProjectService {
.subtract(methods[params.method ?? "week"].daysBack, "days")
.toDate();

const contacts = await prisma.$queryRaw`
WITH date_range AS (
SELECT generate_series(
(SELECT DATE_TRUNC('day', MIN("createdAt")) FROM contacts),
DATE_TRUNC('day', NOW()) + INTERVAL '1 day',
INTERVAL '1 day'
) AS day
)
SELECT
dr.day,
SUM(COALESCE(ct.count, 0)) OVER (ORDER BY dr.day) as count
FROM date_range dr
LEFT JOIN (
SELECT
DATE_TRUNC('day', c."createdAt") AS day,
COUNT(c.id) as count
FROM contacts c
WHERE "projectId" = ${params.id}
GROUP BY DATE_TRUNC('day', c."createdAt")
) ct ON dr.day = ct.day
WHERE dr.day < DATE_TRUNC('day', NOW())
ORDER BY dr.day DESC
LIMIT 30;
`;

const rawActionClicks = await prisma.$queryRaw`
SELECT clicks."link", a."name", count(clicks.id)::int FROM clicks
JOIN emails e on clicks."emailId" = e.id
JOIN actions a on e."actionId" = a.id
WHERE clicks."link" NOT LIKE '%unsubscribe%' AND DATE(clicks."createdAt") BETWEEN DATE(${start}) AND DATE(${end}) AND a."projectId" = ${params.id}
GROUP BY a."name", clicks."link"
`;

const combinedRoutes = {};

// @ts-expect-error
const contacts = await prisma.$queryRawTyped(sql.contacts(params.id));

const rawActionClicks = await prisma.$queryRawTyped(sql.rawActionClicks(start, end, params.id))

const combinedRoutes: Record<string, { link: string, name: string, count: number }> = {};

rawActionClicks.forEach((item) => {
const url = new URL(item.link);
const route = url.pathname;
// @ts-expect-error
if (combinedRoutes[route]) {
// @ts-expect-error
combinedRoutes[route].count += item.count;
combinedRoutes[route].count += (item.count ?? 0);
} else {
// @ts-expect-error
combinedRoutes[route] = {
link: url.hostname + route,
name: item.name,
count: item.count,
count: item.count ?? 0,
};
}
});

const formattedActionClicks = Object.values(combinedRoutes).sort(
// @ts-expect-error
(a, b) => b.count - a.count,
);

Expand Down
3 changes: 2 additions & 1 deletion prisma/schema.prisma
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
generator client {
provider = "prisma-client-js"
provider = "prisma-client-js"
previewFeatures = ["typedSql"]
}

datasource db {
Expand Down
23 changes: 23 additions & 0 deletions prisma/sql/contacts.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
WITH date_range AS (
SELECT generate_series(
(SELECT DATE_TRUNC('day', MIN("createdAt")) FROM contacts),
DATE_TRUNC('day', NOW()) + INTERVAL '1 day',
INTERVAL '1 day'
) AS day
)

SELECT
dr.day,
SUM(COALESCE(ct.count, 0)) OVER (ORDER BY dr.day) as count
FROM date_range dr
LEFT JOIN (
SELECT
DATE_TRUNC('day', c."createdAt") AS day,
COUNT(c.id) as count
FROM contacts c
WHERE "projectId" = $1
GROUP BY DATE_TRUNC('day', c."createdAt")
) ct ON dr.day = ct.day
WHERE dr.day < DATE_TRUNC('day', NOW())
ORDER BY dr.day DESC
LIMIT 30;
5 changes: 5 additions & 0 deletions prisma/sql/rawActionClicks.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
SELECT clicks."link", a."name", count(clicks.id)::int FROM clicks
JOIN emails e on clicks."emailId" = e.id
JOIN actions a on e."actionId" = a.id
WHERE clicks."link" NOT LIKE '%unsubscribe%' AND DATE(clicks."createdAt") BETWEEN DATE($1) AND DATE($2) AND a."projectId" = $3
GROUP BY a."name", clicks."link"
Loading

0 comments on commit 3a82222

Please sign in to comment.