1
1
import lodash from 'lodash'
2
2
import { FieldTranslatorFactory , OpensearchQueryParser } from '@crowd/opensearch'
3
3
import { PageData } from '@crowd/common'
4
- import { OpenSearchIndex , SyncStatus } from '@crowd/types'
4
+ import { IOrganization , IOrganizationIdentity , OpenSearchIndex , SyncStatus } from '@crowd/types'
5
5
import Sequelize , { QueryTypes } from 'sequelize'
6
6
import SequelizeRepository from './sequelizeRepository'
7
7
import AuditLogRepository from './auditLogRepository'
@@ -300,9 +300,7 @@ class OrganizationRepository {
300
300
record = await record . update (
301
301
{
302
302
...lodash . pick ( data , [
303
- 'name' ,
304
303
'displayName' ,
305
- 'url' ,
306
304
'description' ,
307
305
'emails' ,
308
306
'phoneNumbers' ,
@@ -446,6 +444,129 @@ class OrganizationRepository {
446
444
}
447
445
}
448
446
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
+
449
570
static async findById ( id , options : IRepositoryOptions ) {
450
571
const transaction = SequelizeRepository . getTransaction ( options )
451
572
const sequelize = SequelizeRepository . getSequelize ( options )
@@ -455,44 +576,43 @@ class OrganizationRepository {
455
576
const results = await sequelize . query (
456
577
`
457
578
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
+ )
496
616
SELECT
497
617
o.*,
498
618
COALESCE(ac."activityCount", 0)::INTEGER AS "activityCount",
0 commit comments