Skip to content

Commit 10b4328

Browse files
committed
organization identities
1 parent 7a2b2ca commit 10b4328

File tree

14 files changed

+810
-245
lines changed

14 files changed

+810
-245
lines changed
Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1 @@
1+
drop table if exists "public"."organizationIdentities";
Lines changed: 123 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,123 @@
1+
create table "organizationIdentities" (
2+
"organizationId" uuid not null references organizations on delete cascade,
3+
platform text not null,
4+
name text not null,
5+
"sourceId" text,
6+
"url" text,
7+
"tenantId" uuid not null references tenants on delete cascade,
8+
"integrationId" uuid,
9+
"createdAt" timestamp with time zone default now() not null,
10+
"updatedAt" timestamp with time zone default now() not null,
11+
primary key ("organizationId", platform, name),
12+
unique (platform, name, "tenantId")
13+
);
14+
create index "ix_organizationIdentities" on "organizationIdentities" (platform, name, "organizationId");
15+
create index "ix_organizationIdentities_tenantId" on "organizationIdentities" ("tenantId");
16+
create index "ix_organizationIdentities_organizationId" on "organizationIdentities" ("organizationId");
17+
create index "organizationIdentities_createdAt_index" on "organizationIdentities" ("createdAt" desc);
18+
create index "organizationIdentities_name_index" on "organizationIdentities" (name);
19+
create trigger organization_identities_updated_at before
20+
update on "organizationIdentities" for each row execute procedure trigger_set_updated_at();
21+
22+
23+
alter table organizations
24+
add "weakIdentities" jsonb default '[]'::jsonb not null;
25+
26+
BEGIN;
27+
DO
28+
$$
29+
DECLARE
30+
org organizations%ROWTYPE;
31+
act activities%ROWTYPE;
32+
gin integrations%ROWTYPE;
33+
BEGIN
34+
FOR org IN SELECT * FROM organizations
35+
LOOP
36+
-- check for organization activity on github
37+
SELECT INTO act * FROM activities WHERE "platform" = 'github' AND "organizationId" = org.id LIMIT 1;
38+
BEGIN
39+
-- If activity is found
40+
IF FOUND THEN
41+
SELECT INTO gin *
42+
FROM integrations
43+
WHERE "platform" = 'github'
44+
AND "tenantId" = org."tenantId"
45+
AND "deletedAt" IS NULL
46+
LIMIT 1;
47+
-- If integration is found
48+
IF FOUND THEN
49+
INSERT INTO "organizationIdentities" ("organizationId", "platform", "name", "url",
50+
"sourceId", "integrationId", "tenantId")
51+
VALUES (org.id, 'github', org.name, org.url, null, gin.id, org."tenantId");
52+
-- If integration is not found, `platform` is set to 'custom' and `integrationId` is set to null
53+
ELSE
54+
INSERT INTO "organizationIdentities" ("organizationId", "platform", "name", "sourceId",
55+
"integrationId", "tenantId")
56+
VALUES (org.id, 'custom', org.name, null, null, org."tenantId");
57+
END IF;
58+
-- If no activity is found, `platform` is set to 'custom' and `integrationId` is set to null
59+
ELSE
60+
INSERT INTO "organizationIdentities" ("organizationId", "platform", "name", "sourceId",
61+
"integrationId", "tenantId")
62+
VALUES (org.id, 'custom', org.name, null, null, org."tenantId");
63+
END IF;
64+
EXCEPTION
65+
WHEN unique_violation THEN
66+
-- If conflict happens, insert this identity into organizations."weakIdentities" jsonb array
67+
UPDATE organizations
68+
SET "weakIdentities" = COALESCE("weakIdentities", '{}'::jsonb) ||
69+
jsonb_build_object('platform', 'github', 'name', org.name)
70+
WHERE id = org.id;
71+
END;
72+
73+
-- check for non-null LinkedIn handle
74+
IF org.linkedin -> 'handle' IS NOT NULL THEN
75+
BEGIN
76+
INSERT INTO "organizationIdentities" ("organizationId", "platform", "name", "sourceId",
77+
"integrationId", "tenantId", "url")
78+
VALUES (org.id, 'linkedin', replace(org.linkedin ->> 'handle', 'company/', ''), null, null,
79+
org."tenantId", CONCAT('https://linkedin.com/company/',
80+
replace(org.linkedin ->> 'handle', 'company/', '')));
81+
EXCEPTION
82+
WHEN unique_violation THEN
83+
-- If conflict happens, insert this identity into organizations."weakIdentities" jsonb array
84+
UPDATE organizations
85+
SET "weakIdentities" = COALESCE("weakIdentities", '{}'::jsonb) ||
86+
jsonb_build_object('platform', 'linkedin', 'name',
87+
replace(org.linkedin ->> 'handle', 'company/', ''),
88+
'url', CONCAT('https://linkedin.com/company/',
89+
replace(org.linkedin ->> 'handle', 'company/', '')))
90+
WHERE id = org.id;
91+
END;
92+
END IF;
93+
94+
-- check for non-null Twitter handle
95+
IF org.twitter -> 'handle' IS NOT NULL THEN
96+
BEGIN
97+
INSERT INTO "organizationIdentities" ("organizationId", "platform", "name", "sourceId",
98+
"integrationId", "tenantId", "url")
99+
VALUES (org.id, 'twitter', org.twitter ->> 'handle'::text, null, null, org."tenantId",
100+
CONCAT('https://twitter.com/', org.twitter ->> 'handle'::text));
101+
EXCEPTION
102+
WHEN unique_violation THEN
103+
-- If conflict happens, insert this identity into organizations."weakIdentities" jsonb array
104+
UPDATE organizations
105+
SET "weakIdentities" = COALESCE("weakIdentities", '{}'::jsonb) ||
106+
jsonb_build_object('platform', 'twitter', 'name',
107+
org.twitter ->> 'handle', 'url',
108+
CONCAT('https://twitter.com/', org.twitter ->> 'handle'::text))
109+
WHERE id = org.id;
110+
END;
111+
END IF;
112+
END LOOP;
113+
END ;
114+
$$;
115+
116+
COMMIT;
117+
118+
119+
drop index if exists "organizations_name_tenant_id";
120+
121+
-- alter table organizations DROP COLUMN "name";
122+
--
123+
-- alter table organizations DROP COLUMN "url";

backend/src/database/repositories/organizationRepository.ts

Lines changed: 161 additions & 41 deletions
Original file line numberDiff line numberDiff line change
@@ -1,7 +1,7 @@
11
import lodash from 'lodash'
22
import { FieldTranslatorFactory, OpensearchQueryParser } from '@crowd/opensearch'
33
import { PageData } from '@crowd/common'
4-
import { OpenSearchIndex, SyncStatus } from '@crowd/types'
4+
import { IOrganization, IOrganizationIdentity, OpenSearchIndex, SyncStatus } from '@crowd/types'
55
import Sequelize, { QueryTypes } from 'sequelize'
66
import SequelizeRepository from './sequelizeRepository'
77
import AuditLogRepository from './auditLogRepository'
@@ -300,9 +300,7 @@ class OrganizationRepository {
300300
record = await record.update(
301301
{
302302
...lodash.pick(data, [
303-
'name',
304303
'displayName',
305-
'url',
306304
'description',
307305
'emails',
308306
'phoneNumbers',
@@ -446,6 +444,129 @@ class OrganizationRepository {
446444
}
447445
}
448446

447+
static async addIdentity(
448+
organizationId: string,
449+
identity: IOrganizationIdentity,
450+
options: IRepositoryOptions,
451+
): Promise<void> {
452+
const transaction = SequelizeRepository.getTransaction(options)
453+
const sequelize = SequelizeRepository.getSequelize(options)
454+
const currentTenant = SequelizeRepository.getCurrentTenant(options)
455+
456+
const query = `
457+
insert into
458+
"organizationIdentities"("organizationId", "platform", "name", "url", "sourceId", "tenantId", "integrationId", "createdAt")
459+
values
460+
(:organizationId, :platform, :name, :url, :sourceId, :tenantId, :integrationId, now())
461+
on conflict do nothing;
462+
`
463+
464+
await sequelize.query(query, {
465+
replacements: {
466+
organizationId,
467+
platform: identity.platform,
468+
sourceId: identity.sourceId || null,
469+
url: identity.url || null,
470+
tenantId: currentTenant.id,
471+
integrationId: identity.integrationId || null,
472+
name: identity.name,
473+
},
474+
type: QueryTypes.INSERT,
475+
transaction,
476+
})
477+
}
478+
479+
static async getIdentities(
480+
organizationId: string,
481+
options: IRepositoryOptions,
482+
): Promise<IOrganizationIdentity[]> {
483+
const transaction = SequelizeRepository.getTransaction(options)
484+
const sequelize = SequelizeRepository.getSequelize(options)
485+
const currentTenant = SequelizeRepository.getCurrentTenant(options)
486+
487+
const results = await sequelize.query(
488+
`
489+
select "sourceId", "platform", "name", "integrationId" from "organizationIdentities"
490+
where "organizationId" = :organizationId and "tenantId" = :tenantId
491+
`,
492+
{
493+
replacements: {
494+
organizationId,
495+
tenantId: currentTenant.id,
496+
},
497+
type: QueryTypes.SELECT,
498+
transaction,
499+
},
500+
)
501+
502+
return results as IOrganizationIdentity[]
503+
}
504+
505+
static async findByIdentity(
506+
segmentId: string,
507+
identity: IOrganizationIdentity,
508+
options: IRepositoryOptions,
509+
): Promise<IOrganization> {
510+
const transaction = SequelizeRepository.getTransaction(options)
511+
const sequelize = SequelizeRepository.getSequelize(options)
512+
const currentTenant = SequelizeRepository.getCurrentTenant(options)
513+
514+
const results = await sequelize.query(
515+
`
516+
with
517+
"organizationsWithIdentity" as (
518+
select os."organizationId"
519+
from "organizationSegments" os
520+
join "organizationIdentities" oi on os."organizationId" = oi."organizationId"
521+
where
522+
os."segmentId" = :segmentId
523+
and oi.platform = :platform
524+
and oi.name = :name
525+
)
526+
select o.id,
527+
o.url,
528+
o.description,
529+
o.emails,
530+
o.logo,
531+
o.tags,
532+
o.github,
533+
o.twitter,
534+
o.linkedin,
535+
o.crunchbase,
536+
o.employees,
537+
o.location,
538+
o.website,
539+
o.type,
540+
o.size,
541+
o.headline,
542+
o.industry,
543+
o.founded,
544+
o.attributes
545+
from organizations o
546+
where o."tenantId" = :tenantId
547+
and o.id in (select "organizationId" from "organizationsWithIdentity");
548+
`,
549+
{
550+
replacements: {
551+
segmentId,
552+
tenantId: currentTenant.id,
553+
name: identity.name,
554+
platform: identity.platform,
555+
},
556+
type: QueryTypes.SELECT,
557+
transaction,
558+
},
559+
)
560+
561+
if (results.length === 0) {
562+
return null
563+
}
564+
565+
const result = results[0] as IOrganization
566+
567+
return result
568+
}
569+
449570
static async findById(id, options: IRepositoryOptions) {
450571
const transaction = SequelizeRepository.getTransaction(options)
451572
const sequelize = SequelizeRepository.getSequelize(options)
@@ -455,44 +576,43 @@ class OrganizationRepository {
455576
const results = await sequelize.query(
456577
`
457578
WITH
458-
activity_counts AS (
459-
SELECT "organizationId", COUNT(id) AS "activityCount"
460-
FROM activities
461-
WHERE "organizationId" = :id
462-
GROUP BY "organizationId"
463-
),
464-
member_counts AS (
465-
SELECT "organizationId", COUNT(DISTINCT "memberId") AS "memberCount"
466-
FROM "memberOrganizations"
467-
WHERE "organizationId" = :id and "dateEnd" is null
468-
GROUP BY "organizationId"
469-
),
470-
active_on AS (
471-
SELECT "organizationId", ARRAY_AGG(DISTINCT platform) AS "activeOn"
472-
FROM activities
473-
WHERE "organizationId" = :id
474-
GROUP BY "organizationId"
475-
),
476-
identities AS (
477-
SELECT "organizationId", ARRAY_AGG(DISTINCT platform) AS "identities"
478-
FROM "memberOrganizations" mo
479-
JOIN "memberIdentities" mi ON mi."memberId" = mo."memberId"
480-
WHERE mo."organizationId" = :id
481-
GROUP BY "organizationId"
482-
),
483-
last_active AS (
484-
SELECT mo."organizationId", MAX(timestamp) AS "lastActive", MIN(timestamp) AS "joinedAt"
485-
FROM "memberOrganizations" mo
486-
JOIN activities a ON a."memberId" = mo."memberId"
487-
WHERE mo."organizationId" = :id
488-
GROUP BY mo."organizationId"
489-
),
490-
segments AS (
491-
SELECT "organizationId", ARRAY_AGG("segmentId") AS "segments"
492-
FROM "organizationSegments"
493-
WHERE "organizationId" = :id
494-
GROUP BY "organizationId"
495-
)
579+
activity_counts AS (
580+
SELECT "organizationId", COUNT(id) AS "activityCount"
581+
FROM activities
582+
WHERE "organizationId" = :id
583+
GROUP BY "organizationId"
584+
),
585+
member_counts AS (
586+
SELECT "organizationId", COUNT(DISTINCT "memberId") AS "memberCount"
587+
FROM "memberOrganizations"
588+
WHERE "organizationId" = :id and "dateEnd" is null
589+
GROUP BY "organizationId"
590+
),
591+
active_on AS (
592+
SELECT "organizationId", ARRAY_AGG(DISTINCT platform) AS "activeOn"
593+
FROM activities
594+
WHERE "organizationId" = :id
595+
GROUP BY "organizationId"
596+
),
597+
identities AS (
598+
SELECT oi."organizationId", jsonb_agg(oi) AS "identities"
599+
FROM "organizationIdentities" oi
600+
WHERE oi."organizationId" = :id
601+
GROUP BY "organizationId"
602+
),
603+
last_active AS (
604+
SELECT mo."organizationId", MAX(timestamp) AS "lastActive", MIN(timestamp) AS "joinedAt"
605+
FROM "memberOrganizations" mo
606+
JOIN activities a ON a."memberId" = mo."memberId"
607+
WHERE mo."organizationId" = :id
608+
GROUP BY mo."organizationId"
609+
),
610+
segments AS (
611+
SELECT "organizationId", ARRAY_AGG("segmentId") AS "segments"
612+
FROM "organizationSegments"
613+
WHERE "organizationId" = :id
614+
GROUP BY "organizationId"
615+
)
496616
SELECT
497617
o.*,
498618
COALESCE(ac."activityCount", 0)::INTEGER AS "activityCount",

0 commit comments

Comments
 (0)