Skip to content

Commit

Permalink
Merge pull request #1340 from Giveth/staging
Browse files Browse the repository at this point in the history
v1.23.1 2024-02-18(third release)
  • Loading branch information
jainkrati authored Feb 18, 2024
2 parents 7e30466 + 7651980 commit 9e6adfd
Show file tree
Hide file tree
Showing 10 changed files with 116 additions and 43 deletions.
2 changes: 1 addition & 1 deletion migration/1708269524103-project_actual_matching_view_v4.ts
Original file line number Diff line number Diff line change
Expand Up @@ -152,7 +152,7 @@ export class ProjectActualMatchingViewV41708269524103
)
AND d2."qfRoundUserScore" >= qr."minimumPassportScore"
AND (s.id IS NULL OR s."confirmedSybil" = false)
AND pf.id IS NULL
AND (pf.id IS NULL OR pf."confirmedFraud" = false)
GROUP BY
p2.id,
p2.title,
Expand Down
94 changes: 94 additions & 0 deletions migration/1708280336872-project_actual_matching_view_v5.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,94 @@
import { MigrationInterface, QueryRunner } from 'typeorm';

export class ProjectActualMatchingViewV51708280336872
implements MigrationInterface
{
public async up(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(`
DROP MATERIALIZED VIEW IF EXISTS project_actual_matching_view;
CREATE MATERIALIZED VIEW project_actual_matching_view AS
WITH DonationsBeforeAnalysis AS (
SELECT
p.id,
p.slug,
p.title,
qr.id as "qfId",
qr."minimumPassportScore" as "minimumPassportScore",
STRING_AGG(distinct pa."networkId" || '-' || pa."address", ', ') AS "networkAddresses",
COALESCE(SUM(d."valueUsd"), 0) AS "allUsdReceived",
COUNT(DISTINCT d."fromWalletAddress") AS "totalDonors"
FROM
public.donation AS d
INNER JOIN project p ON p.id = d."projectId"
INNER JOIN qf_round qr ON qr.id = d."qfRoundId"
INNER JOIN project_address pa ON pa."projectId" = p.id AND pa."networkId" = ANY(qr."eligibleNetworks")
LEFT JOIN project_fraud pf ON pf."projectId" = p.id AND pf."qfRoundId" = qr.id
WHERE
pf.id IS NULL
GROUP BY
p.id,
p.title,
p.slug,
qr.id
),
DonationsAfterAnalysis AS (
SELECT
p2.id,
p2.slug,
p2.title,
qr.id as "qfId",
COALESCE(SUM(d2."valueUsd"), 0) AS "allUsdReceivedAfterSybilsAnalysis",
COUNT(DISTINCT d2."fromWalletAddress") AS "uniqueDonors",
SUM(SQRT(d2."valueUsd")) AS "donationsSqrtRootSum",
POWER(SUM(SQRT(d2."valueUsd")), 2) as "donationsSqrtRootSumSquared"
FROM
public.donation AS d2
INNER JOIN project p2 ON p2.id = d2."projectId"
INNER JOIN qf_round qr ON qr.id = d2."qfRoundId"
INNER JOIN project_address pa ON pa."projectId" = p2.id AND pa."networkId" = ANY(qr."eligibleNetworks")
LEFT JOIN user_passport_score ups ON ups."userId" = d2."userId" AND ups."qfRoundId" = qr.id
LEFT JOIN "sybil" s ON s."userId" = d2."userId" AND s."qfRoundId" = qr.id
LEFT JOIN project_fraud pf ON pf."projectId" = p2.id AND pf."qfRoundId" = qr.id
WHERE
p2."statusId" = 5
AND LOWER(d2."fromWalletAddress") NOT IN (
SELECT DISTINCT LOWER(pa.address) AS "projectAddress"
FROM public.project_address pa
JOIN project p3 ON p3.id = pa."projectId"
AND p3."verified" = true
AND p3."statusId" = 5
AND p3."isImported" = false
)
AND (ups."passportScore" IS NULL OR ups."passportScore" >= qr."minimumPassportScore")
AND s.id IS NULL
AND pf.id IS NULL
GROUP BY
p2.id,
p2.title,
p2.slug,
qr.id
)
SELECT
d1.id AS "projectId",
d1.title,
d1.slug,
d1."networkAddresses",
d1."qfId" AS "qfRoundId",
d1."allUsdReceived",
d1."totalDonors",
d2."allUsdReceivedAfterSybilsAnalysis",
d2."uniqueDonors",
d2."donationsSqrtRootSum",
d2."donationsSqrtRootSumSquared"
FROM
DonationsBeforeAnalysis d1
INNER JOIN DonationsAfterAnalysis d2 ON d1.id = d2.id AND d1.slug = d2.slug AND d1."qfId" = d2."qfId";
CREATE INDEX idx_project_actual_matching_project_id ON project_actual_matching_view USING hash ("projectId");
CREATE INDEX idx_project_actual_matching_qf_round_id ON project_actual_matching_view USING hash ("qfRoundId");
`);
}

public async down(queryRunner: QueryRunner): Promise<void> {}
}
4 changes: 2 additions & 2 deletions package-lock.json

Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.

2 changes: 1 addition & 1 deletion package.json
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
{
"name": "giveth-graphql-api",
"version": "1.23.0",
"version": "1.23.1",
"description": "Backend GraphQL server for Giveth originally forked from Topia",
"main": "./dist/index.js",
"dependencies": {
Expand Down
4 changes: 0 additions & 4 deletions src/entities/projectFraud.ts
Original file line number Diff line number Diff line change
Expand Up @@ -17,10 +17,6 @@ export class ProjectFraud extends BaseEntity {
@PrimaryGeneratedColumn()
readonly id: number;

@Field({ nullable: false })
@Column('boolean', { nullable: false, default: false })
confirmedFraud: boolean;

@Field(type => Project)
@ManyToOne(type => Project, { eager: true })
project: Project;
Expand Down
4 changes: 0 additions & 4 deletions src/entities/sybil.ts
Original file line number Diff line number Diff line change
Expand Up @@ -19,10 +19,6 @@ export class Sybil extends BaseEntity {
@PrimaryGeneratedColumn()
readonly id: number;

@Field({ nullable: false })
@Column('boolean', { nullable: false, default: false })
confirmedSybil: boolean;

@Field(type => User)
@ManyToOne(type => User, { eager: true })
user: User;
Expand Down
10 changes: 5 additions & 5 deletions src/repositories/userPassportScoreRepository.ts
Original file line number Diff line number Diff line change
Expand Up @@ -37,11 +37,11 @@ export async function fetchUsersAndRoundsNeedingPassportScore(

const query = `
SELECT d."userId", d."qfRoundId"
FROM Donation d
JOIN QfRound qfr ON d."qfRoundId" = qfr.id
LEFT JOIN UserPassportScore ups ON d."userId" = ups."userId" AND d."qfRoundId" = ups."qfRoundId"
WHERE qfr.endDate < CURRENT_DATE
AND qfr.endDate > TIMESTAMP '${startDate}'
FROM donation d
JOIN qf_round qfr ON d."qfRoundId" = qfr.id
LEFT JOIN user_passport_score ups ON d."userId" = ups."userId" AND d."qfRoundId" = ups."qfRoundId"
WHERE qfr."endDate" < CURRENT_DATE
AND qfr."endDate" > TIMESTAMP '${startDate}'
AND ups.id IS NULL;
`;

Expand Down
2 changes: 1 addition & 1 deletion src/repositories/userRepository.test.ts
Original file line number Diff line number Diff line change
Expand Up @@ -439,7 +439,7 @@ function findUserByIdTestCases() {
}

function findAllUsersTestCases() {
it('should return all users, count sould work fine', async () => {
it('should return all users, count should work fine', async () => {
const { count, users } = await findAllUsers({ take: 7, skip: 0 });
assert.equal(users.length, 7);
const newUser = await saveUserDirectlyToDb(generateRandomEtheriumAddress());
Expand Down
17 changes: 6 additions & 11 deletions src/server/adminJs/tabs/projectFraudTab.ts
Original file line number Diff line number Diff line change
Expand Up @@ -21,7 +21,7 @@ export const createProjectFraud = async (

let type = 'success';
try {
const { projectId, qfRoundId, csvData, confirmedFraud } = request.payload;
const { projectId, qfRoundId, csvData } = request.payload;
if (csvData) {
// Parse the CSV data
const jsonArray = await csv().fromString(csvData);
Expand Down Expand Up @@ -54,7 +54,7 @@ export const createProjectFraud = async (
.map(obj => {
const slugProjectId = projectIdsMap.get(obj.slug.toLowerCase());
return slugProjectId
? `(true, ${Number(slugProjectId)}, ${Number(obj.qfRoundId)})`
? `(${Number(slugProjectId)}, ${Number(obj.qfRoundId)})`
: null;
})
.join(',');
Expand All @@ -65,15 +65,15 @@ export const createProjectFraud = async (

// Insert query
const query = `
INSERT INTO project_fraud ("confirmedFraud", "projectId", "qfRoundId")
INSERT INTO project_fraud ("projectId", "qfRoundId")
VALUES ${values};
ON CONFLICT ("projectId", "qfRoundId") DO UPDATE
`;

// Execute the query
await ProjectFraud.query(query);
} else {
const projectFraud = new ProjectFraud();
projectFraud.confirmedFraud = confirmedFraud;
projectFraud.projectId = projectId;
projectFraud.qfRoundId = qfRoundId;
await projectFraud.save();
Expand Down Expand Up @@ -104,9 +104,6 @@ export const ProjectFraudTab = {

options: {
properties: {
confirmedFraud: {
isVisible: true,
},
projectId: {
isVisible: true,
},
Expand Down Expand Up @@ -145,19 +142,17 @@ export const ProjectFraudTab = {
),
},
delete: {
isVisible: false,
isAccessible: ({ currentAdmin }) =>
canAccessProjectStatusReasonAction(
{ currentAdmin },
ResourceActions.DELETE,
ResourceActions.EDIT,
),
},
bulkDelete: {
isVisible: false,
isAccessible: ({ currentAdmin }) =>
canAccessProjectStatusReasonAction(
{ currentAdmin },
ResourceActions.BULK_DELETE,
ResourceActions.EDIT,
),
},
},
Expand Down
20 changes: 6 additions & 14 deletions src/server/adminJs/tabs/sybilTab.ts
Original file line number Diff line number Diff line change
Expand Up @@ -21,7 +21,7 @@ export const createSybil = async (

let type = 'success';
try {
const { userId, qfRoundId, csvData, confirmedSybil } = request.payload;
const { userId, qfRoundId, csvData } = request.payload;
if (csvData) {
// Parse the CSV data
const jsonArray = await csv().fromString(csvData);
Expand Down Expand Up @@ -54,7 +54,7 @@ export const createSybil = async (
obj.walletAddress.toLowerCase(),
);
return walletAddressUserId
? `(true, ${walletAddressUserId}, ${Number(obj.qfRoundId)})`
? `(${walletAddressUserId}, ${Number(obj.qfRoundId)})`
: null;
})
// .filter(value => value !== null) // Filter out any rows where userId was not found
Expand All @@ -66,17 +66,14 @@ export const createSybil = async (

// Upsert query
const upsertQuery = `
INSERT INTO sybil ("confirmedSybil", "userId", "qfRoundId")
INSERT INTO sybil ( "userId", "qfRoundId")
VALUES ${values}
ON CONFLICT ("userId", "qfRoundId")
DO UPDATE SET
"confirmedSybil" = EXCLUDED."confirmedSybil";
ON CONFLICT ("userId", "qfRoundId") DO UPDATE
`;
// Execute the query
await Sybil.query(upsertQuery);
} else {
const sybil = new Sybil();
sybil.confirmedSybil = true;
sybil.userId = userId;
sybil.qfRoundId = qfRoundId;
await sybil.save();
Expand Down Expand Up @@ -104,9 +101,6 @@ export const SybilTab = {

options: {
properties: {
confirmedSybil: {
isVisible: true,
},
userId: {
isVisible: true,
},
Expand Down Expand Up @@ -145,19 +139,17 @@ export const SybilTab = {
),
},
delete: {
isVisible: false,
isAccessible: ({ currentAdmin }) =>
canAccessProjectStatusReasonAction(
{ currentAdmin },
ResourceActions.DELETE,
ResourceActions.EDIT,
),
},
bulkDelete: {
isVisible: false,
isAccessible: ({ currentAdmin }) =>
canAccessProjectStatusReasonAction(
{ currentAdmin },
ResourceActions.BULK_DELETE,
ResourceActions.EDIT,
),
},
},
Expand Down

0 comments on commit 9e6adfd

Please sign in to comment.