2023-09-14 20:31:49 +08:00
- - unaccent will be used to create nameSortable
CREATE EXTENSION IF NOT EXISTS unaccent ;
CREATE OR REPLACE FUNCTION immutable_lower_unaccent ( text )
RETURNS text AS $ $
SELECT lower ( unaccent ( ' unaccent ' , $ 1 ) )
$ $ LANGUAGE SQL IMMUTABLE ;
2024-06-18 22:11:59 +08:00
- - remove_emojis will be used to create nameSortable
CREATE OR REPLACE FUNCTION remove_emojis ( text ) RETURNS text AS $ $
DECLARE
input_string ALIAS FOR $ 1 ;
output_string text ;
BEGIN
output_string : = regexp_replace ( input_string , ' [^\u0000-\uFFFF] ' , ' ' , ' g ' ) ;
RETURN output_string ;
END ;
$ $ LANGUAGE plpgsql IMMUTABLE ;
2023-03-25 00:33:08 +08:00
-- ========== Meeting tables
create table " meeting " (
" meetingId " varchar ( 100 ) primary key ,
" extId " varchar ( 100 ) ,
" name " varchar ( 100 ) ,
" isBreakout " boolean ,
" disabledFeatures " varchar [ ] ,
" meetingCameraCap " integer ,
" maxPinnedCameras " integer ,
" notifyRecordingIsOn " boolean ,
" presentationUploadExternalDescription " text ,
" presentationUploadExternalUrl " varchar ( 500 ) ,
" learningDashboardAccessToken " varchar ( 100 ) ,
2024-04-25 04:40:35 +08:00
" loginUrl " varchar ( 500 ) ,
2023-12-13 04:42:44 +08:00
" logoutUrl " varchar ( 500 ) ,
2024-01-24 22:33:38 +08:00
" customLogoUrl " varchar ( 500 ) ,
2024-08-22 01:58:32 +08:00
" customDarkLogoUrl " varchar ( 500 ) ,
2024-01-24 22:33:38 +08:00
" bannerText " text ,
" bannerColor " varchar ( 50 ) ,
2023-03-25 00:33:08 +08:00
" createdTime " bigint ,
2024-02-05 22:31:31 +08:00
" durationInSeconds " integer ,
2024-03-21 23:49:33 +08:00
" endWhenNoModerator " boolean ,
" endWhenNoModeratorDelayInMinutes " integer ,
2024-02-07 00:26:48 +08:00
" endedAt " timestamp with time zone ,
" endedReasonCode " varchar ( 200 ) ,
" endedBy " varchar ( 50 )
2023-03-25 00:33:08 +08:00
) ;
2024-01-09 19:31:12 +08:00
ALTER TABLE " meeting " ADD COLUMN " createdAt " timestamp with time zone GENERATED ALWAYS AS ( to_timestamp ( " createdTime " : : double precision / 1000 ) ) STORED ;
2024-02-05 22:31:31 +08:00
ALTER TABLE " meeting " ADD COLUMN " ended " boolean GENERATED ALWAYS AS ( " endedAt " is not null ) STORED ;
2024-01-09 19:31:12 +08:00
2023-06-23 22:23:41 +08:00
create index " idx_meeting_extId " on " meeting " ( " extId " ) ;
2023-03-25 00:33:08 +08:00
create table " meeting_breakout " (
" meetingId " varchar ( 100 ) primary key references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" parentId " varchar ( 100 ) ,
" sequence " integer ,
" freeJoin " boolean ,
" breakoutRooms " varchar [ ] ,
" record " boolean ,
" privateChatEnabled " boolean ,
" captureNotes " boolean ,
" captureSlides " boolean ,
" captureNotesFilename " varchar ( 100 ) ,
" captureSlidesFilename " varchar ( 100 )
) ;
2023-04-01 04:46:17 +08:00
create index " idx_meeting_breakout_meetingId " on " meeting_breakout " ( " meetingId " ) ;
2023-05-20 00:47:00 +08:00
create view " v_meeting_breakoutPolicies " as select * from meeting_breakout ;
2023-03-25 00:33:08 +08:00
2023-07-29 03:13:01 +08:00
create table " meeting_recordingPolicies " (
2023-03-25 00:33:08 +08:00
" meetingId " varchar ( 100 ) primary key references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
2023-04-12 22:30:12 +08:00
" record " boolean ,
" autoStartRecording " boolean ,
" allowStartStopRecording " boolean ,
2023-08-08 21:41:16 +08:00
" keepEvents " boolean
2023-07-29 03:13:01 +08:00
) ;
create view " v_meeting_recordingPolicies " as select * from " meeting_recordingPolicies " ;
create table " meeting_recording " (
" meetingId " varchar ( 100 ) references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
2023-08-08 21:41:16 +08:00
" startedAt " timestamp with time zone ,
2023-07-29 03:13:01 +08:00
" startedBy " varchar ( 50 ) ,
2023-08-08 21:41:16 +08:00
" stoppedAt " timestamp with time zone ,
2023-07-29 03:13:01 +08:00
" stoppedBy " varchar ( 50 ) ,
2023-08-08 21:41:16 +08:00
" recordedTimeInSeconds " integer ,
2023-07-29 03:13:01 +08:00
CONSTRAINT " meeting_recording_pkey " PRIMARY KEY ( " meetingId " , " startedAt " )
2023-03-25 00:33:08 +08:00
) ;
2023-04-01 04:46:17 +08:00
create index " idx_meeting_recording_meetingId " on " meeting_recording " ( " meetingId " ) ;
2023-07-29 03:13:01 +08:00
2023-08-08 21:41:16 +08:00
- - Set recordedTimeInSeconds when stoppedAt is updated
CREATE OR REPLACE FUNCTION " update_meeting_recording_trigger_func " ( ) RETURNS TRIGGER AS $ $
BEGIN
NEW . " recordedTimeInSeconds " : = CASE WHEN NEW . " startedAt " IS NULL OR NEW . " stoppedAt " IS NULL THEN 0
ELSE EXTRACT ( EPOCH FROM ( NEW . " stoppedAt " - NEW . " startedAt " ) )
END ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
2023-11-02 03:29:37 +08:00
CREATE TRIGGER " update_meeting_recording_trigger " BEFORE UPDATE OF " stoppedAt " ON " meeting_recording "
2023-08-08 21:41:16 +08:00
FOR EACH ROW EXECUTE FUNCTION " update_meeting_recording_trigger_func " ( ) ;
- - ALTER TABLE " meeting_recording " ADD COLUMN " recordedTimeInSeconds " integer GENERATED ALWAYS AS
- - ( CASE WHEN " startedAt " IS NULL OR " stoppedAt " IS NULL THEN 0 ELSE EXTRACT ( EPOCH FROM ( " stoppedAt " - " startedAt " ) ) END ) STORED ;
2023-07-29 03:13:01 +08:00
CREATE VIEW v_meeting_recording AS
SELECT r . * ,
CASE
WHEN " startedAt " IS NULL THEN false
WHEN " stoppedAt " IS NULL THEN true
ELSE " startedAt " > " stoppedAt "
END AS " isRecording "
FROM (
select " meetingId " ,
( array_agg ( " startedAt " ORDER BY " startedAt " DESC ) ) [ 1 ] as " startedAt " ,
( array_agg ( " startedBy " ORDER BY " startedAt " DESC ) ) [ 1 ] as " startedBy " ,
( array_agg ( " stoppedAt " ORDER BY " startedAt " DESC ) ) [ 1 ] as " stoppedAt " ,
( array_agg ( " stoppedBy " ORDER BY " startedAt " DESC ) ) [ 1 ] as " stoppedBy " ,
2023-08-11 21:39:58 +08:00
coalesce ( sum ( " recordedTimeInSeconds " ) , 0 ) " previousRecordedTimeInSeconds "
2023-07-29 03:13:01 +08:00
from " meeting_recording "
GROUP BY " meetingId "
) r ;
2023-03-25 00:33:08 +08:00
create table " meeting_welcome " (
2023-05-20 02:28:20 +08:00
" meetingId " varchar ( 100 ) primary key references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
2023-04-12 22:30:12 +08:00
" welcomeMsg " text ,
2023-05-20 02:28:20 +08:00
" welcomeMsgForModerators " text
2023-03-25 00:33:08 +08:00
) ;
2023-04-01 04:46:17 +08:00
create index " idx_meeting_welcome_meetingId " on " meeting_welcome " ( " meetingId " ) ;
2023-03-25 00:33:08 +08:00
create table " meeting_voice " (
" meetingId " varchar ( 100 ) primary key references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
2023-04-12 22:30:12 +08:00
" telVoice " varchar ( 100 ) ,
" voiceConf " varchar ( 100 ) ,
" dialNumber " varchar ( 100 ) ,
2023-03-25 00:33:08 +08:00
" muteOnStart " boolean
) ;
2023-04-01 04:46:17 +08:00
create index " idx_meeting_voice_meetingId " on " meeting_voice " ( " meetingId " ) ;
2023-05-20 00:47:00 +08:00
create view " v_meeting_voiceSettings " as select * from meeting_voice ;
2023-03-25 00:33:08 +08:00
2023-04-12 22:07:54 +08:00
create table " meeting_usersPolicies " (
2023-03-25 00:33:08 +08:00
" meetingId " varchar ( 100 ) primary key references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
2024-06-02 21:01:15 +08:00
" maxUsers " integer ,
" maxUserConcurrentAccesses " integer ,
" webcamsOnlyForModerator " boolean ,
" userCameraCap " integer ,
" guestPolicy " varchar ( 100 ) ,
" guestLobbyMessage " text ,
" meetingLayout " varchar ( 100 ) ,
" allowModsToUnmuteUsers " boolean ,
" allowModsToEjectCameras " boolean ,
" authenticatedGuest " boolean ,
" allowPromoteGuestToModerator " boolean
2023-03-25 00:33:08 +08:00
) ;
2023-04-12 22:07:54 +08:00
create index " idx_meeting_usersPolicies_meetingId " on " meeting_usersPolicies " ( " meetingId " ) ;
2023-05-03 00:29:30 +08:00
CREATE OR REPLACE VIEW " v_meeting_usersPolicies " AS
SELECT " meeting_usersPolicies " . " meetingId " ,
" meeting_usersPolicies " . " maxUsers " ,
" meeting_usersPolicies " . " maxUserConcurrentAccesses " ,
" meeting_usersPolicies " . " webcamsOnlyForModerator " ,
" meeting_usersPolicies " . " userCameraCap " ,
" meeting_usersPolicies " . " guestPolicy " ,
2023-06-29 10:21:31 +08:00
" meeting_usersPolicies " . " guestLobbyMessage " ,
2023-05-03 00:29:30 +08:00
" meeting_usersPolicies " . " meetingLayout " ,
" meeting_usersPolicies " . " allowModsToUnmuteUsers " ,
" meeting_usersPolicies " . " allowModsToEjectCameras " ,
" meeting_usersPolicies " . " authenticatedGuest " ,
2024-06-02 21:01:15 +08:00
" meeting_usersPolicies " . " allowPromoteGuestToModerator " ,
2023-05-03 00:29:30 +08:00
" meeting " . " isBreakout " is false " moderatorsCanMuteAudio " ,
" meeting " . " isBreakout " is false and " meeting_usersPolicies " . " allowModsToUnmuteUsers " is true " moderatorsCanUnmuteAudio "
FROM " meeting_usersPolicies "
JOIN " meeting " using ( " meetingId " ) ;
2023-03-25 00:33:08 +08:00
2024-03-21 02:26:17 +08:00
create table " meeting_metadata " (
" meetingId " varchar ( 100 ) references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
2024-10-14 20:15:29 +08:00
" name " varchar ( 255 ) ,
" value " varchar ( 1000 ) ,
2024-03-21 02:26:17 +08:00
CONSTRAINT " meeting_metadata_pkey " PRIMARY KEY ( " meetingId " , " name " )
) ;
create index " idx_meeting_metadata_meetingId " on " meeting_metadata " ( " meetingId " ) ;
CREATE OR REPLACE VIEW " v_meeting_metadata " AS
SELECT " meeting_metadata " . " meetingId " ,
" meeting_metadata " . " name " ,
" meeting_metadata " . " value "
FROM " meeting_metadata " ;
2023-03-25 00:33:08 +08:00
create table " meeting_lockSettings " (
" meetingId " varchar ( 100 ) primary key references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" disableCam " boolean ,
" disableMic " boolean ,
" disablePrivateChat " boolean ,
" disablePublicChat " boolean ,
" disableNotes " boolean ,
" hideUserList " boolean ,
" lockOnJoin " boolean ,
" lockOnJoinConfigurable " boolean ,
2023-10-03 22:53:47 +08:00
" hideViewersCursor " boolean ,
" hideViewersAnnotation " boolean
2023-03-25 00:33:08 +08:00
) ;
2023-04-01 04:46:17 +08:00
create index " idx_meeting_lockSettings_meetingId " on " meeting_lockSettings " ( " meetingId " ) ;
2023-03-25 00:33:08 +08:00
2023-04-11 02:57:35 +08:00
CREATE OR REPLACE VIEW " v_meeting_lockSettings " AS
SELECT
mls . " meetingId " ,
mls . " disableCam " ,
mls . " disableMic " ,
mls . " disablePrivateChat " ,
mls . " disablePublicChat " ,
mls . " disableNotes " ,
mls . " hideUserList " ,
mls . " hideViewersCursor " ,
2023-10-03 22:53:47 +08:00
mls . " hideViewersAnnotation " ,
2024-03-21 23:49:33 +08:00
mls . " lockOnJoin " ,
mls . " lockOnJoinConfigurable " ,
2023-04-12 22:30:12 +08:00
mup . " webcamsOnlyForModerator " ,
2023-04-11 02:57:35 +08:00
CASE WHEN
mls . " disableCam " IS TRUE THEN TRUE
WHEN mls . " disableMic " IS TRUE THEN TRUE
WHEN mls . " disablePrivateChat " IS TRUE THEN TRUE
WHEN mls . " disablePublicChat " IS TRUE THEN TRUE
WHEN mls . " disableNotes " IS TRUE THEN TRUE
WHEN mls . " hideUserList " IS TRUE THEN TRUE
WHEN mls . " hideViewersCursor " IS TRUE THEN TRUE
2023-10-03 22:53:47 +08:00
WHEN mls . " hideViewersAnnotation " IS TRUE THEN TRUE
2023-04-12 22:30:12 +08:00
WHEN mup . " webcamsOnlyForModerator " IS TRUE THEN TRUE
2023-04-11 02:57:35 +08:00
ELSE FALSE
END " hasActiveLockSetting "
FROM meeting m
JOIN " meeting_lockSettings " mls ON mls . " meetingId " = m . " meetingId "
2023-04-12 22:30:12 +08:00
JOIN " meeting_usersPolicies " mup ON mup . " meetingId " = m . " meetingId " ;
2023-04-11 02:57:35 +08:00
2023-10-11 09:38:26 +08:00
create table " meeting_clientSettings " (
" meetingId " varchar ( 100 ) primary key references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
2023-11-02 00:26:38 +08:00
" clientSettingsJson " jsonb
2023-10-11 09:38:26 +08:00
) ;
CREATE VIEW " v_meeting_clientSettings " AS SELECT * FROM " meeting_clientSettings " ;
2023-12-08 07:48:13 +08:00
create view " v_meeting_clientPluginSettings " as
select " meetingId " ,
plugin - > > ' name ' as " name " ,
plugin - > > ' url ' as " url " ,
( plugin - > > ' settings ' ) : : jsonb as " settings " ,
( plugin - > > ' dataChannels ' ) : : jsonb as " dataChannels "
from (
select " meetingId " , jsonb_array_elements ( " clientSettingsJson " - > ' public ' - > ' plugins ' ) AS plugin
from " meeting_clientSettings "
) settings ;
2023-04-19 04:40:46 +08:00
2023-03-25 00:33:08 +08:00
create table " meeting_group " (
" meetingId " varchar ( 100 ) references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" groupId " varchar ( 100 ) ,
" name " varchar ( 100 ) ,
" usersExtId " varchar [ ] ,
CONSTRAINT " meeting_group_pkey " PRIMARY KEY ( " meetingId " , " groupId " )
) ;
2023-04-01 04:46:17 +08:00
create index " idx_meeting_group_meetingId " on " meeting_group " ( " meetingId " ) ;
2023-05-20 00:47:00 +08:00
create view " v_meeting_group " as select * from meeting_group ;
2023-03-25 00:33:08 +08:00
-- ========== User tables
2023-04-06 00:56:22 +08:00
CREATE TABLE " user " (
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" userId " varchar ( 50 ) NOT NULL ,
2023-06-30 03:52:59 +08:00
" extId " varchar ( 50 ) ,
" name " varchar ( 255 ) ,
" role " varchar ( 20 ) ,
" avatar " varchar ( 500 ) ,
2024-08-23 20:04:56 +08:00
" webcamBackground " varchar ( 500 ) ,
2023-06-30 03:52:59 +08:00
" color " varchar ( 7 ) ,
2024-01-19 00:01:16 +08:00
" authToken " varchar ( 16 ) ,
2023-06-30 03:52:59 +08:00
" authed " bool ,
" joined " bool ,
2024-10-16 21:37:14 +08:00
" firstJoinedAt " timestamp with time zone ,
2023-11-11 04:36:10 +08:00
" joinErrorCode " varchar ( 50 ) ,
" joinErrorMessage " varchar ( 400 ) ,
2023-06-30 03:52:59 +08:00
" banned " bool ,
" loggedOut " bool , -- when user clicked Leave meeting button
2024-10-16 23:30:02 +08:00
" bot " bool , -- used to flag au
2023-06-30 03:52:59 +08:00
" guest " bool , - - used for dialIn
2023-06-29 10:08:03 +08:00
" guestStatus " varchar ( 50 ) ,
2023-06-30 03:52:59 +08:00
" registeredOn " bigint ,
" excludeFromDashboard " bool ,
2023-11-20 22:53:53 +08:00
" enforceLayout " varchar ( 50 ) ,
2024-03-18 21:58:53 +08:00
- - columns of user state below
2023-06-29 10:08:03 +08:00
" raiseHand " bool default false ,
2023-08-08 21:41:16 +08:00
" raiseHandTime " timestamp with time zone ,
2023-06-29 10:08:03 +08:00
" away " bool default false ,
2023-08-08 21:41:16 +08:00
" awayTime " timestamp with time zone ,
2024-06-10 20:48:38 +08:00
" reactionEmoji " varchar ( 25 ) ,
" reactionEmojiTime " timestamp with time zone ,
2024-04-16 23:35:27 +08:00
" guestStatusSetByModerator " varchar ( 50 ) ,
2023-06-29 10:08:03 +08:00
" guestLobbyMessage " text ,
2023-06-30 03:52:59 +08:00
" mobile " bool ,
2023-03-17 00:56:32 +08:00
" clientType " varchar ( 50 ) ,
2024-04-17 23:24:25 +08:00
" transferredFromParentMeeting " bool default false , - - when a user join in breakoutRoom only in audio
2023-11-16 21:59:08 +08:00
" disconnected " bool default false , -- this is the old leftFlag (that was renamed), set when the user just closed the client
" expired " bool default false , -- when it is been some time the user is disconnected
2023-06-30 03:52:59 +08:00
" ejected " bool ,
2023-06-29 10:08:03 +08:00
" ejectReason " varchar ( 255 ) ,
" ejectReasonCode " varchar ( 50 ) ,
2024-03-20 01:12:19 +08:00
" ejectedByModerator " varchar ( 50 ) ,
2023-06-30 03:52:59 +08:00
" presenter " bool ,
" pinned " bool ,
" locked " bool ,
2023-07-05 21:05:25 +08:00
" speechLocale " varchar ( 255 ) ,
2024-06-04 04:14:32 +08:00
" captionLocale " varchar ( 255 ) ,
2024-03-20 01:12:19 +08:00
" inactivityWarningDisplay " bool default FALSE ,
" inactivityWarningTimeoutSecs " numeric ,
2023-07-20 06:13:21 +08:00
" hasDrawPermissionOnCurrentPage " bool default FALSE ,
2024-04-16 23:35:27 +08:00
" echoTestRunningAt " timestamp with time zone ,
CONSTRAINT " user_pkey " PRIMARY KEY ( " meetingId " , " userId " ) ,
FOREIGN KEY ( " meetingId " , " guestStatusSetByModerator " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE SET NULL
2023-03-08 23:23:45 +08:00
) ;
2024-05-02 22:50:19 +08:00
create index " idx_user_pk_reverse " on " user " ( " userId " , " meetingId " ) ;
2023-04-01 04:46:17 +08:00
CREATE INDEX " idx_user_meetingId " ON " user " ( " meetingId " ) ;
2023-06-23 22:23:41 +08:00
CREATE INDEX " idx_user_extId " ON " user " ( " meetingId " , " extId " ) ;
2023-03-08 23:23:45 +08:00
2024-10-23 04:03:14 +08:00
-- user (on update raiseHand or away: set new time)
CREATE OR REPLACE FUNCTION update_user_raiseHand_away_time_trigger_func ( )
RETURNS TRIGGER AS $ $
BEGIN
IF NEW . " raiseHand " IS DISTINCT FROM OLD . " raiseHand " THEN
IF NEW . " raiseHand " is false THEN
NEW . " raiseHandTime " : = NULL ;
ELSE
NEW . " raiseHandTime " : = NOW ( ) ;
END IF ;
END IF ;
IF NEW . " away " IS DISTINCT FROM OLD . " away " THEN
IF NEW . " away " is false THEN
NEW . " awayTime " : = NULL ;
ELSE
NEW . " awayTime " : = NOW ( ) ;
END IF ;
END IF ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER update_user_raiseHand_away_time_trigger BEFORE UPDATE OF " raiseHand " , " away " ON " user "
FOR EACH ROW EXECUTE FUNCTION update_user_raiseHand_away_time_trigger_func ( ) ;
2023-04-20 20:49:16 +08:00
- - hasDrawPermissionOnCurrentPage is necessary to improve the performance of the order by of userlist
COMMENT ON COLUMN " user " . " hasDrawPermissionOnCurrentPage " IS ' This column is dynamically populated by triggers of tables: user, pres_presentation, pres_page, pres_page_writers ' ;
2023-04-26 02:50:23 +08:00
COMMENT ON COLUMN " user " . " disconnected " IS ' This column is set true when the user closes the window or his with the server is over ' ;
COMMENT ON COLUMN " user " . " expired " IS ' This column is set true after 10 seconds with disconnected=true ' ;
COMMENT ON COLUMN " user " . " loggedOut " IS ' This column is set to true when the user click the button to Leave meeting ' ;
2023-04-20 20:49:16 +08:00
2024-08-28 22:08:30 +08:00
- - Virtual columns isDialIn , isModerator , currentlyInMeeting , isWaiting , isAllowed , isDenied
2023-06-29 10:30:02 +08:00
ALTER TABLE " user " ADD COLUMN " isDialIn " boolean GENERATED ALWAYS AS ( " clientType " = ' dial-in-user ' ) STORED ;
ALTER TABLE " user " ADD COLUMN " isWaiting " boolean GENERATED ALWAYS AS ( " guestStatus " = ' WAIT ' ) STORED ;
ALTER TABLE " user " ADD COLUMN " isAllowed " boolean GENERATED ALWAYS AS ( " guestStatus " = ' ALLOW ' ) STORED ;
ALTER TABLE " user " ADD COLUMN " isDenied " boolean GENERATED ALWAYS AS ( " guestStatus " = ' DENY ' ) STORED ;
2023-12-07 02:17:30 +08:00
ALTER TABLE " user " ADD COLUMN " registeredAt " timestamp with time zone GENERATED ALWAYS AS ( to_timestamp ( " registeredOn " : : double precision / 1000 ) ) STORED ;
2024-10-16 21:37:14 +08:00
- - Populate column ` firstJoinedAt ` to register if the user has joined in the meeting ( once column ` joined ` turn false when user leaves )
CREATE OR REPLACE FUNCTION " set_user_firstJoinedAt_trigger_func " ( )
RETURNS TRIGGER AS $ $
BEGIN
IF NEW . " joined " is true AND NEW . " firstJoinedAt " IS NULL THEN
NEW . " firstJoinedAt " : = NOW ( ) ;
END IF ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER " set_user_firstJoinedAt_ins_trigger "
BEFORE INSERT ON " user "
FOR EACH ROW
EXECUTE FUNCTION " set_user_firstJoinedAt_trigger_func " ( ) ;
CREATE TRIGGER " set_user_firstJoinedAt_upd_trigger "
BEFORE UPDATE ON " user "
FOR EACH ROW
WHEN ( OLD . " joined " IS DISTINCT FROM NEW . " joined " )
EXECUTE FUNCTION " set_user_firstJoinedAt_trigger_func " ( ) ;
2023-09-14 20:49:38 +08:00
- - Used to sort the Userlist
2024-06-18 22:11:59 +08:00
ALTER TABLE " user " ADD COLUMN " nameSortable " varchar ( 255 ) GENERATED ALWAYS AS ( trim ( remove_emojis ( immutable_lower_unaccent ( " name " ) ) ) ) STORED ;
2023-09-14 20:31:49 +08:00
2023-06-29 10:30:02 +08:00
CREATE INDEX " idx_user_waiting " ON " user " ( " meetingId " ) where " isWaiting " is true ;
2024-06-13 03:21:31 +08:00
ALTER TABLE " user " ADD COLUMN " isModerator " boolean GENERATED ALWAYS AS ( CASE WHEN " role " = ' MODERATOR ' THEN true ELSE false END ) STORED ;
2024-08-28 22:08:30 +08:00
ALTER TABLE " user " ADD COLUMN " currentlyInMeeting " boolean GENERATED ALWAYS AS (
2024-06-13 03:21:31 +08:00
CASE WHEN
" user " . " joined " IS true
AND " user " . " expired " IS false
AND " user " . " loggedOut " IS false
AND " user " . " ejected " IS NOT true
THEN true
ELSE false
END ) STORED ;
2023-04-12 22:07:54 +08:00
CREATE OR REPLACE VIEW " v_user "
AS SELECT " user " . " userId " ,
" user " . " extId " ,
" user " . " meetingId " ,
" user " . " name " ,
2023-09-14 20:31:49 +08:00
" user " . " nameSortable " ,
2023-04-12 22:07:54 +08:00
" user " . " avatar " ,
" user " . " color " ,
2023-06-29 10:08:03 +08:00
" user " . " away " ,
" user " . " awayTime " ,
" user " . " raiseHand " ,
" user " . " raiseHandTime " ,
2024-06-10 20:48:38 +08:00
" user " . " reactionEmoji " ,
" user " . " reactionEmojiTime " ,
2024-10-16 23:30:02 +08:00
" user " . " bot " ,
2023-04-12 22:07:54 +08:00
" user " . " guest " ,
" user " . " guestStatus " ,
" user " . " mobile " ,
" user " . " clientType " ,
2023-04-20 20:49:16 +08:00
" user " . " isDialIn " ,
2023-04-12 22:07:54 +08:00
" user " . " role " ,
" user " . " authed " ,
" user " . " joined " ,
2023-04-26 02:41:37 +08:00
" user " . " disconnected " ,
" user " . " expired " ,
2023-04-12 22:07:54 +08:00
" user " . " banned " ,
" user " . " loggedOut " ,
" user " . " registeredOn " ,
2023-09-05 22:31:25 +08:00
" user " . " registeredAt " ,
2023-04-12 22:07:54 +08:00
" user " . " presenter " ,
" user " . " pinned " ,
2023-10-12 19:33:37 +08:00
CASE WHEN " user " . " role " = ' MODERATOR ' THEN false ELSE " user " . " locked " END " locked " ,
2023-07-05 21:05:25 +08:00
" user " . " speechLocale " ,
2024-06-04 04:14:32 +08:00
" user " . " captionLocale " ,
2023-07-20 06:13:21 +08:00
CASE WHEN " user " . " echoTestRunningAt " > current_timestamp - INTERVAL ' 3 seconds ' THEN TRUE ELSE FALSE END " isRunningEchoTest " ,
2023-04-20 20:49:16 +08:00
" user " . " hasDrawPermissionOnCurrentPage " ,
2023-04-12 22:07:54 +08:00
CASE WHEN " user " . " role " = ' MODERATOR ' THEN true ELSE false END " isModerator " ,
2024-08-28 22:08:30 +08:00
" user " . " currentlyInMeeting "
2024-06-13 03:21:31 +08:00
FROM " user "
2024-08-28 22:08:30 +08:00
WHERE " user " . " currentlyInMeeting " is true ;
2023-04-26 02:41:37 +08:00
CREATE INDEX " idx_v_user_meetingId " ON " user " ( " meetingId " )
where " user " . " loggedOut " IS FALSE
AND " user " . " expired " IS FALSE
2023-09-26 22:32:05 +08:00
AND " user " . " ejected " IS NOT TRUE
2023-04-26 02:41:37 +08:00
and " user " . " joined " IS TRUE ;
2024-06-18 22:11:59 +08:00
CREATE INDEX " idx_v_user_meetingId_orderByColumns " ON " user " (
" meetingId " ,
" presenter " ,
" role " ,
" raiseHandTime " ,
" isDialIn " ,
" hasDrawPermissionOnCurrentPage " ,
" nameSortable " ,
" registeredAt " ,
" userId "
)
2024-08-28 22:08:30 +08:00
where " user " . " currentlyInMeeting " is true ;
2023-04-20 20:49:16 +08:00
2023-04-17 23:04:38 +08:00
CREATE OR REPLACE VIEW " v_user_current "
AS SELECT " user " . " userId " ,
" user " . " extId " ,
2024-01-19 00:01:16 +08:00
" user " . " authToken " ,
2023-04-17 23:04:38 +08:00
" user " . " meetingId " ,
" user " . " name " ,
2023-09-14 20:31:49 +08:00
" user " . " nameSortable " ,
2023-04-17 23:04:38 +08:00
" user " . " avatar " ,
2024-08-23 20:04:56 +08:00
" user " . " webcamBackground " ,
2023-04-17 23:04:38 +08:00
" user " . " color " ,
2023-06-29 10:08:03 +08:00
" user " . " away " ,
" user " . " raiseHand " ,
2024-06-10 20:48:38 +08:00
" user " . " reactionEmoji " ,
2023-04-17 23:04:38 +08:00
" user " . " guest " ,
2023-12-13 04:42:44 +08:00
" user " . " guestStatus " ,
2023-04-17 23:04:38 +08:00
" user " . " mobile " ,
" user " . " clientType " ,
2023-11-20 22:53:53 +08:00
" user " . " enforceLayout " ,
2023-04-20 20:49:16 +08:00
" user " . " isDialIn " ,
2023-04-17 23:04:38 +08:00
" user " . " role " ,
" user " . " authed " ,
" user " . " joined " ,
2023-11-11 04:36:10 +08:00
" user " . " joinErrorCode " ,
" user " . " joinErrorMessage " ,
2023-04-26 02:41:37 +08:00
" user " . " disconnected " ,
" user " . " expired " ,
2023-06-29 10:08:03 +08:00
" user " . " ejected " ,
" user " . " ejectReason " ,
" user " . " ejectReasonCode " ,
2023-04-17 23:04:38 +08:00
" user " . " banned " ,
" user " . " loggedOut " ,
" user " . " registeredOn " ,
2023-09-05 22:31:25 +08:00
" user " . " registeredAt " ,
2023-04-17 23:04:38 +08:00
" user " . " presenter " ,
" user " . " pinned " ,
2023-10-12 19:33:37 +08:00
CASE WHEN " user " . " role " = ' MODERATOR ' THEN false ELSE " user " . " locked " END " locked " ,
2023-07-05 21:05:25 +08:00
" user " . " speechLocale " ,
2024-06-04 04:14:32 +08:00
" user " . " captionLocale " ,
2023-04-20 20:49:16 +08:00
" user " . " hasDrawPermissionOnCurrentPage " ,
2023-07-20 06:13:21 +08:00
" user " . " echoTestRunningAt " ,
CASE WHEN " user " . " echoTestRunningAt " > current_timestamp - INTERVAL ' 3 seconds ' THEN TRUE ELSE FALSE END " isRunningEchoTest " ,
2024-01-19 00:01:16 +08:00
CASE WHEN " user " . " role " = ' MODERATOR ' THEN true ELSE false END " isModerator " ,
2024-08-28 22:08:30 +08:00
" user " . " currentlyInMeeting " ,
2024-03-20 01:12:19 +08:00
" user " . " inactivityWarningDisplay " ,
" user " . " inactivityWarningTimeoutSecs "
2023-04-17 23:04:38 +08:00
FROM " user " ;
2023-06-29 10:08:03 +08:00
CREATE OR REPLACE VIEW " v_user_guest " AS
SELECT u . " meetingId " , u . " userId " ,
u . " guestStatus " ,
2023-06-29 10:30:02 +08:00
u . " isWaiting " ,
2023-12-07 02:17:30 +08:00
rank ( ) OVER (
PARTITION BY u . " meetingId "
ORDER BY u . " registeredOn " ASC , u . " userId " ASC
) as " positionInWaitingQueue " ,
2023-06-29 10:30:02 +08:00
u . " isAllowed " ,
u . " isDenied " ,
2023-12-13 04:42:44 +08:00
COALESCE ( NULL IF ( u . " guestLobbyMessage " , ' ' ) , NULL IF ( mup . " guestLobbyMessage " , ' ' ) ) AS " guestLobbyMessage "
2023-06-29 10:08:03 +08:00
FROM " user " u
2023-12-07 02:17:30 +08:00
JOIN " meeting_usersPolicies " mup using ( " meetingId " )
2024-06-06 04:41:23 +08:00
where u . " guestStatus " = ' WAIT '
and u . " loggedOut " is false ;
2023-06-29 10:08:03 +08:00
2023-04-12 22:07:54 +08:00
- - v_user_ref will be used only as foreign key ( not possible to fetch this table directly through graphql )
- - it is necessary because v_user has some conditions like " lockSettings-hideUserList "
- - but viewers still needs to query this users as foreign key of chat , cameras , etc
CREATE OR REPLACE VIEW " v_user_ref "
2024-04-16 23:35:27 +08:00
AS SELECT
2023-04-12 22:07:54 +08:00
" user " . " meetingId " ,
2024-04-16 23:35:27 +08:00
" user " . " userId " ,
" user " . " extId " ,
2023-04-12 22:07:54 +08:00
" user " . " name " ,
2023-09-14 20:31:49 +08:00
" user " . " nameSortable " ,
2023-04-12 22:07:54 +08:00
" user " . " avatar " ,
" user " . " color " ,
2023-06-29 10:08:03 +08:00
" user " . " away " ,
" user " . " raiseHand " ,
2024-06-10 20:48:38 +08:00
" user " . " reactionEmoji " ,
2023-04-12 22:07:54 +08:00
" user " . " guest " ,
" user " . " guestStatus " ,
" user " . " mobile " ,
" user " . " clientType " ,
2023-04-20 20:49:16 +08:00
" user " . " isDialIn " ,
2023-04-12 22:07:54 +08:00
" user " . " role " ,
" user " . " authed " ,
" user " . " joined " ,
2023-04-26 02:41:37 +08:00
" user " . " disconnected " ,
" user " . " expired " ,
2023-04-12 22:07:54 +08:00
" user " . " banned " ,
" user " . " loggedOut " ,
" user " . " registeredOn " ,
2023-09-05 22:31:25 +08:00
" user " . " registeredAt " ,
2023-04-12 22:07:54 +08:00
" user " . " presenter " ,
" user " . " pinned " ,
2023-10-12 19:33:37 +08:00
CASE WHEN " user " . " role " = ' MODERATOR ' THEN false ELSE " user " . " locked " END " locked " ,
2023-07-05 21:05:25 +08:00
" user " . " speechLocale " ,
2024-06-04 04:14:32 +08:00
" user " . " captionLocale " ,
2023-04-20 20:49:16 +08:00
" user " . " hasDrawPermissionOnCurrentPage " ,
2023-04-12 22:07:54 +08:00
CASE WHEN " user " . " role " = ' MODERATOR ' THEN true ELSE false END " isModerator " ,
2024-08-28 22:08:30 +08:00
" user " . " currentlyInMeeting "
2023-04-12 22:07:54 +08:00
FROM " user " ;
2023-04-06 00:56:22 +08:00
2024-10-16 21:37:14 +08:00
- - Provide users that have joined in the meeting , either who is currently in meeting or has left
CREATE OR REPLACE VIEW " v_user_presenceLog "
AS SELECT
" user " . " meetingId " ,
" user " . " userId " ,
" user " . " extId " ,
CASE WHEN " user " . " role " = ' MODERATOR ' THEN true ELSE false END " isModerator " ,
" user " . " currentlyInMeeting "
FROM " user "
where " firstJoinedAt " is not null ;
2024-07-17 01:40:49 +08:00
create table " user_metadata " (
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) ,
" userId " varchar ( 50 ) ,
2023-05-20 00:47:00 +08:00
" parameter " varchar ( 255 ) ,
2024-10-14 20:15:29 +08:00
" value " varchar ( 1000 ) ,
2024-07-17 01:40:49 +08:00
CONSTRAINT " user_metadata_pkey " PRIMARY KEY ( " meetingId " , " userId " , " parameter " ) ,
2024-04-16 23:35:27 +08:00
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2023-05-20 00:47:00 +08:00
) ;
2024-07-17 01:40:49 +08:00
create index " idx_user_metadata_pk_reverse " on " user_metadata " ( " userId " , " meetingId " ) ;
2023-05-20 00:47:00 +08:00
2024-07-17 01:40:49 +08:00
CREATE VIEW " v_user_metadata " AS
2024-04-16 23:35:27 +08:00
SELECT *
2024-07-17 01:40:49 +08:00
FROM " user_metadata " ;
2023-05-20 00:47:00 +08:00
2023-05-20 02:28:20 +08:00
CREATE VIEW " v_user_welcomeMsgs " AS
SELECT
u . " meetingId " ,
u . " userId " ,
w . " welcomeMsg " ,
CASE WHEN u . " role " = ' MODERATOR ' THEN w . " welcomeMsgForModerators " ELSE NULL END " welcomeMsgForModerators "
FROM " user " u
join meeting_welcome w USING ( " meetingId " ) ;
2024-09-06 05:04:25 +08:00
create table " user_lockSettings " (
" meetingId " varchar ( 100 ) ,
" userId " varchar ( 50 ) ,
" disablePublicChat " boolean ,
CONSTRAINT " user_lockSettings_pkey " PRIMARY KEY ( " meetingId " , " userId " ) ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
) ;
create index " idx_user_lockSettings_pk_reverse " on " user_lockSettings " ( " userId " , " meetingId " ) ;
2024-09-10 00:46:08 +08:00
CREATE VIEW " v_user_lockSettings " as
SELECT
l . " meetingId " ,
l . " userId " ,
case when " user " . " isModerator " then false else l . " disablePublicChat " end " disablePublicChat "
FROM " user_lockSettings " l
join " user " on " user " . " meetingId " = l . " meetingId " and " user " . " userId " = l . " userId " ;
2023-05-20 02:28:20 +08:00
2023-03-25 00:33:08 +08:00
CREATE TABLE " user_voice " (
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) ,
" userId " varchar ( 50 ) ,
2023-04-04 20:02:41 +08:00
" voiceUserId " varchar ( 100 ) ,
2023-03-17 00:56:32 +08:00
" callerName " varchar ( 100 ) ,
" callerNum " varchar ( 100 ) ,
" callingWith " varchar ( 100 ) ,
2023-06-30 03:52:59 +08:00
" joined " boolean ,
" listenOnly " boolean ,
" muted " boolean ,
" spoke " boolean ,
" talking " boolean ,
" floor " boolean ,
2023-03-08 23:23:45 +08:00
" lastFloorTime " varchar ( 25 ) ,
2023-03-17 00:56:32 +08:00
" voiceConf " varchar ( 100 ) ,
2023-11-16 21:59:08 +08:00
" voiceConfCallSession " varchar ( 50 ) ,
" voiceConfClientSession " varchar ( 10 ) ,
" voiceConfCallState " varchar ( 30 ) ,
2023-06-30 03:52:59 +08:00
" endTime " bigint ,
2024-04-16 23:35:27 +08:00
" startTime " bigint ,
2024-06-21 01:33:11 +08:00
" voiceActivityAt " timestamp with time zone ,
2024-04-16 23:35:27 +08:00
CONSTRAINT " user_voice_pkey " PRIMARY KEY ( " meetingId " , " userId " ) ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2023-03-08 23:23:45 +08:00
) ;
2024-05-02 22:50:19 +08:00
create index " idx_user_voice_pk_reverse " on " user_voice " ( " userId " , " meetingId " ) ;
2023-04-04 20:02:41 +08:00
- - CREATE INDEX " idx_user_voice_userId " ON " user_voice " ( " userId " ) ;
2024-01-09 19:31:12 +08:00
-- + 6000 means it will hide after 6 seconds
2024-07-13 00:26:26 +08:00
- - ALTER TABLE " user_voice " ADD COLUMN " hideTalkingIndicatorAt " timestamp with time zone
- - GENERATED ALWAYS AS ( to_timestamp ( ( COALESCE ( " endTime " , " startTime " ) + 6000 ) / 1000 ) ) STORED ;
2023-08-23 00:45:33 +08:00
2024-01-09 19:31:12 +08:00
ALTER TABLE " user_voice " ADD COLUMN " startedAt " timestamp with time zone
GENERATED ALWAYS AS ( to_timestamp ( " startTime " : : double precision / 1000 ) ) STORED ;
ALTER TABLE " user_voice " ADD COLUMN " endedAt " timestamp with time zone
GENERATED ALWAYS AS ( to_timestamp ( " endTime " : : double precision / 1000 ) ) STORED ;
2024-04-16 23:35:27 +08:00
CREATE INDEX " idx_user_voice_userId_talking " ON " user_voice " ( " meetingId " , " userId " , " talking " ) ;
2024-07-13 00:26:26 +08:00
- - CREATE INDEX " idx_user_voice_userId_hideTalkingIndicatorAt " ON " user_voice " ( " meetingId " , " userId " , " hideTalkingIndicatorAt " ) ;
2024-06-21 01:33:11 +08:00
CREATE INDEX " idx_user_voice_userId_voiceActivityAt " ON " user_voice " ( " meetingId " , " voiceActivityAt " ) WHERE " voiceActivityAt " is not null ;
2023-03-17 00:56:32 +08:00
2023-03-25 00:33:08 +08:00
CREATE OR REPLACE VIEW " v_user_voice " AS
2024-07-13 00:26:26 +08:00
SELECT " user_voice " . *
2024-04-16 23:35:27 +08:00
FROM " user_voice "
2023-11-16 21:59:08 +08:00
WHERE " user_voice " . " joined " is true ;
2023-03-17 00:56:32 +08:00
2024-06-21 01:33:11 +08:00
- - Populate voiceActivityAt to provide users that are active in audio via stream subscription using the view v_user_voice_activity
CREATE OR REPLACE FUNCTION " update_user_voice_voiceActivityAt_trigger_func " ( ) RETURNS TRIGGER AS $ $
BEGIN
NEW . " voiceActivityAt " : = CASE WHEN
NEW . " muted " IS false
or ( OLD . " muted " IS false and NEW . " muted " is true )
or NEW . " talking " is true
or ( OLD . " talking " IS true and NEW . " talking " is false )
or ( NEW . " startTime " ! = OLD . " startTime " )
or ( NEW . " endTime " ! = OLD . " endTime " )
THEN current_timestamp
ELSE OLD . " voiceActivityAt "
END ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER " update_user_voice_voiceActivityAt_trigger " BEFORE INSERT OR UPDATE ON " user_voice " FOR EACH ROW
EXECUTE FUNCTION " update_user_voice_voiceActivityAt_trigger_func " ( ) ;
CREATE OR REPLACE VIEW " v_user_voice_activity " AS
select
" user_voice " . " meetingId " ,
" user_voice " . " userId " ,
" user_voice " . " muted " ,
" user_voice " . " talking " ,
" user_voice " . " startTime " ,
" user_voice " . " endTime " ,
" user_voice " . " voiceActivityAt "
FROM " user_voice "
WHERE " voiceActivityAt " is not null
AND - - filter recent activities to avoid receiving all history every time it starts the streming
( " voiceActivityAt " > current_timestamp - ' 10 seconds ' : : interval
OR " user_voice " . " muted " is false
OR " user_voice " . " talking " is true
)
;
- - --
2024-02-29 22:08:54 +08:00
2023-03-17 00:56:32 +08:00
CREATE TABLE " user_camera " (
2024-05-08 05:05:36 +08:00
" streamId " varchar ( 150 ) PRIMARY KEY ,
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) ,
" userId " varchar ( 50 ) ,
2024-10-02 01:39:48 +08:00
" contentType " varchar ( 50 ) , - - camera or screenshare
" hasAudio " boolean ,
2024-10-03 09:25:35 +08:00
" showAsContent " boolean ,
2024-04-16 23:35:27 +08:00
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2023-03-17 00:56:32 +08:00
) ;
2024-04-16 23:35:27 +08:00
CREATE INDEX " idx_user_camera_userId " ON " user_camera " ( " meetingId " , " userId " ) ;
2024-05-02 22:50:19 +08:00
CREATE INDEX " idx_user_camera_userId_reverse " ON " user_camera " ( " userId " , " meetingId " ) ;
2024-10-03 09:25:35 +08:00
CREATE INDEX " idx_user_camera_meeting_contentType " ON " user_camera " ( " meetingId " , " contentType " , " showAsContent " ) ;
2023-03-08 23:23:45 +08:00
2023-03-17 00:56:32 +08:00
CREATE OR REPLACE VIEW " v_user_camera " AS
2024-04-16 23:35:27 +08:00
SELECT * FROM " user_camera " ;
2023-03-08 23:23:45 +08:00
2023-03-17 00:56:32 +08:00
CREATE TABLE " user_breakoutRoom " (
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) ,
" userId " varchar ( 50 ) ,
2023-03-17 00:56:32 +08:00
" breakoutRoomId " varchar ( 100 ) ,
" isDefaultName " boolean ,
" sequence " int ,
" shortName " varchar ( 100 ) ,
2024-04-16 23:35:27 +08:00
" currentlyInRoom " boolean ,
CONSTRAINT " user_breakoutRoom_pkey " PRIMARY KEY ( " meetingId " , " userId " ) ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2023-03-17 00:56:32 +08:00
) ;
2024-05-02 22:50:19 +08:00
CREATE INDEX " idx_user_breakoutRoom_pk_reverse " ON " user_breakoutRoom " ( " userId " , " meetingId " ) ;
2023-03-08 23:23:45 +08:00
2023-03-17 00:56:32 +08:00
CREATE OR REPLACE VIEW " v_user_breakoutRoom " AS
2024-04-16 23:35:27 +08:00
SELECT * FROM " user_breakoutRoom " ;
2023-03-29 20:55:41 +08:00
2023-04-06 00:56:22 +08:00
CREATE TABLE " user_connectionStatus " (
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) ,
" userId " varchar ( 50 ) ,
2024-04-01 20:36:28 +08:00
" connectionAliveAtMaxIntervalMs " numeric ,
2023-08-08 21:41:16 +08:00
" connectionAliveAt " timestamp with time zone ,
2024-01-25 23:27:53 +08:00
" networkRttInMs " numeric ,
2023-07-04 22:38:51 +08:00
" status " varchar ( 25 ) ,
2024-04-16 23:35:27 +08:00
" statusUpdatedAt " timestamp with time zone ,
CONSTRAINT " user_connectionStatus_voice_pkey " PRIMARY KEY ( " meetingId " , " userId " ) ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2023-04-06 00:56:22 +08:00
) ;
2024-05-02 22:50:19 +08:00
create index " idx_user_connectionStatus_pk_reverse " on " user_connectionStatus " ( " userId " , " meetingId " ) ;
2023-04-06 00:56:22 +08:00
create index " idx_user_connectionStatus_meetingId " on " user_connectionStatus " ( " meetingId " ) ;
2023-08-08 21:41:16 +08:00
create view " v_user_connectionStatus " as select * from " user_connectionStatus " ;
2024-04-01 20:36:28 +08:00
- - Populate connectionAliveAtMaxIntervalMs to calc clientNotResponding
2024-07-05 04:26:09 +08:00
- - It will sum settings public . stats . interval + public . stats . rtt . critical
2024-04-01 20:36:28 +08:00
CREATE OR REPLACE FUNCTION " update_connectionAliveAtMaxIntervalMs " ( )
RETURNS TRIGGER AS $ $
BEGIN
2024-07-05 04:26:09 +08:00
SELECT ( " clientSettingsJson " - > ' public ' - > ' stats ' - > ' rtt ' - > ' critical ' ) : : int
2024-04-01 20:36:28 +08:00
+
( " clientSettingsJson " - > ' public ' - > ' stats ' - > ' interval ' ) : : int
INTO NEW . " connectionAliveAtMaxIntervalMs "
from " meeting_clientSettings " mcs
where mcs . " meetingId " = NEW . " meetingId " ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER " trigger_update_connectionAliveAtMaxIntervalMs "
BEFORE INSERT ON " user_connectionStatus "
FOR EACH ROW
EXECUTE FUNCTION " update_connectionAliveAtMaxIntervalMs " ( ) ;
2023-07-04 22:38:51 +08:00
- - CREATE TABLE " user_connectionStatusHistory " (
-- "userId" varchar(50) REFERENCES "user"("userId") ON DELETE CASCADE,
-- "status" varchar(25),
2023-08-08 21:51:37 +08:00
-- "statusUpdatedAt" timestamp with time zone
2023-07-04 22:38:51 +08:00
- - ) ;
- - CREATE TABLE " user_connectionStatusHistory " (
-- "userId" varchar(50) REFERENCES "user"("userId") ON DELETE CASCADE,
-- "status" varchar(25),
-- "totalOfOccurrences" integer,
2024-01-25 23:27:53 +08:00
-- "highestNetworkRttInMs" numeric,
2023-08-08 21:41:16 +08:00
-- "statusInsertedAt" timestamp with time zone,
-- "statusUpdatedAt" timestamp with time zone,
2023-07-04 22:38:51 +08:00
-- CONSTRAINT "user_connectionStatusHistory_pkey" PRIMARY KEY ("userId","status")
- - ) ;
CREATE TABLE " user_connectionStatusMetrics " (
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) ,
" userId " varchar ( 50 ) ,
2023-07-04 22:38:51 +08:00
" status " varchar ( 25 ) ,
" occurrencesCount " integer ,
2023-08-08 21:41:16 +08:00
" firstOccurrenceAt " timestamp with time zone ,
" lastOccurrenceAt " timestamp with time zone ,
2024-01-25 23:27:53 +08:00
" lowestNetworkRttInMs " numeric ,
" highestNetworkRttInMs " numeric ,
" lastNetworkRttInMs " numeric ,
2024-04-16 23:35:27 +08:00
CONSTRAINT " user_connectionStatusMetrics_pkey " PRIMARY KEY ( " meetingId " , " userId " , " status " ) ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2023-07-04 22:38:51 +08:00
) ;
2024-05-02 22:50:19 +08:00
create index " idx_user_connectionStatusMetrics_pk_reverse " on " user_connectionStatusMetrics " ( " userId " , " meetingId " ) ;
2023-07-04 22:38:51 +08:00
- - This function populate rtt , status and the table user_connectionStatusMetrics
CREATE OR REPLACE FUNCTION " update_user_connectionStatus_trigger_func " ( ) RETURNS TRIGGER AS $ $
BEGIN
2024-04-01 20:36:28 +08:00
IF NEW . " connectionAliveAt " IS NULL THEN
2023-07-04 22:38:51 +08:00
RETURN NEW ;
END IF ;
2024-04-01 20:36:28 +08:00
2023-07-04 22:38:51 +08:00
- - Update table user_connectionStatusMetrics
WITH upsert AS ( UPDATE " user_connectionStatusMetrics " SET
" occurrencesCount " = " user_connectionStatusMetrics " . " occurrencesCount " + 1 ,
2024-01-25 23:27:53 +08:00
" highestNetworkRttInMs " = GREATEST ( " user_connectionStatusMetrics " . " highestNetworkRttInMs " , NEW . " networkRttInMs " ) ,
" lowestNetworkRttInMs " = LEAST ( " user_connectionStatusMetrics " . " lowestNetworkRttInMs " , NEW . " networkRttInMs " ) ,
" lastNetworkRttInMs " = NEW . " networkRttInMs " ,
2023-07-04 22:38:51 +08:00
" lastOccurrenceAt " = current_timestamp
2024-04-16 23:35:27 +08:00
WHERE " meetingId " = NEW . " meetingId " AND " userId " = NEW . " userId " AND " status " = NEW . " status " RETURNING * )
INSERT INTO " user_connectionStatusMetrics " ( " meetingId " , " userId " , " status " , " occurrencesCount " , " firstOccurrenceAt " ,
2024-01-25 23:27:53 +08:00
" highestNetworkRttInMs " , " lowestNetworkRttInMs " , " lastNetworkRttInMs " )
2024-04-16 23:35:27 +08:00
SELECT NEW . " meetingId " , NEW . " userId " , NEW . " status " , 1 , current_timestamp ,
2024-01-25 23:27:53 +08:00
NEW . " networkRttInMs " , NEW . " networkRttInMs " , NEW . " networkRttInMs "
2023-07-04 22:38:51 +08:00
WHERE NOT EXISTS ( SELECT * FROM upsert ) ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
2024-04-01 20:36:28 +08:00
CREATE TRIGGER " update_user_connectionStatus_trigger " AFTER UPDATE OF " connectionAliveAt " ON " user_connectionStatus "
FOR EACH ROW EXECUTE FUNCTION " update_user_connectionStatus_trigger_func " ( ) ;
2023-07-04 22:38:51 +08:00
CREATE OR REPLACE VIEW " v_user_connectionStatusReport " AS
SELECT u . " meetingId " , u . " userId " ,
max ( cs . " connectionAliveAt " ) AS " connectionAliveAt " ,
max ( cs . " status " ) AS " currentStatus " ,
2024-06-19 00:47:10 +08:00
CASE WHEN
2024-08-28 22:08:30 +08:00
u . " currentlyInMeeting "
2024-06-19 00:47:10 +08:00
AND max ( cs . " connectionAliveAt " ) < current_timestamp - INTERVAL ' 1 millisecond ' * max ( cs . " connectionAliveAtMaxIntervalMs " )
THEN TRUE
ELSE FALSE
END AS " clientNotResponding " ,
2023-07-04 22:38:51 +08:00
( array_agg ( csm . " status " ORDER BY csm . " lastOccurrenceAt " DESC ) ) [ 1 ] as " lastUnstableStatus " ,
max ( csm . " lastOccurrenceAt " ) AS " lastUnstableStatusAt "
FROM " user " u
2024-04-16 23:35:27 +08:00
JOIN " user_connectionStatus " cs ON cs . " meetingId " = u . " meetingId " and cs . " userId " = u . " userId "
LEFT JOIN " user_connectionStatusMetrics " csm ON csm . " meetingId " = u . " meetingId " AND csm . " userId " = u . " userId " AND csm . " status " ! = ' normal '
2023-07-04 22:38:51 +08:00
GROUP BY u . " meetingId " , u . " userId " ;
2024-04-16 23:35:27 +08:00
CREATE INDEX " idx_user_connectionStatusMetrics_UnstableReport " ON " user_connectionStatusMetrics " ( " meetingId " , " userId " ) WHERE " status " ! = ' normal ' ;
2023-07-04 22:38:51 +08:00
2024-09-05 08:22:49 +08:00
CREATE TABLE " user_sessionToken " (
" meetingId " varchar ( 100 ) ,
" userId " varchar ( 50 ) ,
" sessionToken " varchar ( 16 ) ,
2024-09-24 20:40:00 +08:00
" enforceLayout " varchar ( 50 ) ,
2024-09-05 08:22:49 +08:00
" createdAt " timestamp with time zone not null default current_timestamp ,
" removedAt " timestamp with time zone ,
CONSTRAINT " user_sessionToken_pk " PRIMARY KEY ( " meetingId " , " userId " , " sessionToken " ) ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
) ;
CREATE INDEX " idx_user_sessionToken_stk " ON " user_sessionToken " ( " sessionToken " ) ;
create view " v_user_sessionToken " as select * from " user_sessionToken " ;
2023-07-04 22:38:51 +08:00
2023-09-30 07:05:23 +08:00
CREATE TABLE " user_graphqlConnection " (
" graphqlConnectionId " serial PRIMARY KEY ,
" sessionToken " varchar ( 16 ) ,
2024-05-30 04:43:17 +08:00
" clientSessionUUID " varchar ( 36 ) ,
" clientType " varchar ( 50 ) ,
" clientIsMobile " bool ,
2024-02-15 00:28:19 +08:00
" middlewareUID " varchar ( 36 ) ,
2023-09-30 07:05:23 +08:00
" middlewareConnectionId " varchar ( 12 ) ,
2024-02-08 03:21:18 +08:00
" establishedAt " timestamp with time zone ,
2023-09-30 07:05:23 +08:00
" closedAt " timestamp with time zone
) ;
2024-02-08 03:21:18 +08:00
CREATE INDEX " idx_user_graphqlConnectionSessionToken " ON " user_graphqlConnection " ( " sessionToken " ) ;
2023-09-30 07:05:23 +08:00
2024-01-25 23:27:53 +08:00
- - ALTER TABLE " user_connectionStatus " ADD COLUMN " applicationRttInMs " NUMERIC GENERATED ALWAYS AS
2023-07-04 22:38:51 +08:00
- - ( CASE WHEN " connectionAliveAt " IS NULL OR " userClientResponseAt " IS NULL THEN NULL
- - ELSE EXTRACT ( EPOCH FROM ( " userClientResponseAt " - " connectionAliveAt " ) ) * 1000
- - END ) STORED ;
--
- - ALTER TABLE " user_connectionStatus " ADD COLUMN " last " NUMERIC GENERATED ALWAYS AS
- - ( CASE WHEN " connectionAliveAt " IS NULL OR " userClientResponseAt " IS NULL THEN NULL
- - ELSE EXTRACT ( EPOCH FROM ( " userClientResponseAt " - " connectionAliveAt " ) ) * 1000
- - END ) STORED ;
2023-04-06 00:56:22 +08:00
- - CREATE OR REPLACE VIEW " v_user_connectionStatus " AS
- - SELECT u . " meetingId " , u . " userId " , uc . status , uc . " statusUpdatedAt " , uc . " connectionAliveAt " ,
- - CASE WHEN " statusUpdatedAt " < current_timestamp - INTERVAL ' 20 seconds ' THEN TRUE ELSE FALSE END AS " clientNotResponding "
- - FROM " user " u
- - LEFT JOIN " user_connectionStatus " uc ON uc . " userId " = u . " userId " ;
2023-11-02 00:26:38 +08:00
CREATE TABLE " user_clientSettings " (
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) ,
" userId " varchar ( 50 ) ,
" userClientSettingsJson " jsonb ,
CONSTRAINT " user_clientSettings_pkey " PRIMARY KEY ( " meetingId " , " userId " ) ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2023-05-30 00:48:09 +08:00
) ;
2024-05-02 22:50:19 +08:00
CREATE INDEX " idx_user_clientSettings_pk_reverse " ON " user_clientSettings " ( " userId " , " meetingId " ) ;
2023-11-02 00:26:38 +08:00
CREATE INDEX " idx_user_clientSettings_meetingId " ON " user_clientSettings " ( " meetingId " ) ;
2023-05-30 00:48:09 +08:00
2023-11-02 00:26:38 +08:00
create view " v_user_clientSettings " as select * from " user_clientSettings " ;
2023-08-08 21:41:16 +08:00
2023-05-30 00:48:09 +08:00
2023-08-08 19:49:40 +08:00
CREATE TABLE " user_reaction " (
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) ,
" userId " varchar ( 50 ) ,
2023-08-08 19:49:40 +08:00
" reactionEmoji " varchar ( 25 ) ,
2023-10-12 20:55:12 +08:00
" durationInSeconds " integer not null ,
2023-08-08 21:41:16 +08:00
" createdAt " timestamp with time zone not null ,
2024-04-16 23:35:27 +08:00
" expiresAt " timestamp with time zone ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2023-08-08 19:49:40 +08:00
) ;
2024-05-02 22:50:19 +08:00
create index " idx_user_reaction_user_meeting " on " user_reaction " ( " userId " , " meetingId " ) ;
2023-08-08 19:49:40 +08:00
2024-06-10 20:48:38 +08:00
- - Set expiresAt on insert or update user_reaction
- - Set user . reactionEmoji with the latest emoji inserted
2023-08-08 21:41:16 +08:00
CREATE OR REPLACE FUNCTION " update_user_reaction_trigger_func " ( ) RETURNS TRIGGER AS $ $
BEGIN
2024-06-10 20:48:38 +08:00
UPDATE " user "
SET " reactionEmoji " = null if ( lower ( NEW . " reactionEmoji " ) , ' none ' ) ,
" reactionEmojiTime " = case when NULL IF ( LOWER ( NEW . " reactionEmoji " ) , ' none ' ) is null then null else current_timestamp end
WHERE " userId " = NEW . " userId " AND " meetingId " = NEW . " meetingId " ;
2023-10-12 20:55:12 +08:00
NEW . " expiresAt " : = NEW . " createdAt " + ' 1 seconds ' : : INTERVAL * NEW . " durationInSeconds " ;
2023-08-08 21:41:16 +08:00
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER " update_user_reaction_trigger " BEFORE UPDATE ON " user_reaction "
FOR EACH ROW EXECUTE FUNCTION " update_user_reaction_trigger_func " ( ) ;
CREATE TRIGGER " insert_user_reaction_trigger " BEFORE INSERT ON " user_reaction " FOR EACH ROW
EXECUTE FUNCTION " update_user_reaction_trigger_func " ( ) ;
2023-10-12 20:55:12 +08:00
- - ALTER TABLE " user_reaction " ADD COLUMN " expiresAt " timestamp with time zone GENERATED ALWAYS AS ( " createdAt " + ' 1 seconds ' : : INTERVAL * " durationInSeconds " ) STORED ;
2023-08-08 19:49:40 +08:00
2024-04-16 23:35:27 +08:00
CREATE INDEX " idx_user_reaction_userId_createdAt " ON " user_reaction " ( " meetingId " , " userId " , " expiresAt " ) ;
2023-08-08 19:49:40 +08:00
CREATE VIEW v_user_reaction AS
2024-04-16 23:35:27 +08:00
SELECT ur . " meetingId " , ur . " userId " , ur . " reactionEmoji " , ur . " createdAt " , ur . " expiresAt "
2024-05-16 00:39:33 +08:00
FROM " user_reaction " ur
2024-05-16 00:41:59 +08:00
WHERE " expiresAt " > = current_timestamp ;
2023-08-08 19:49:40 +08:00
2024-03-27 22:23:04 +08:00
CREATE TABLE " user_transcriptionError " (
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) ,
" userId " varchar ( 50 ) ,
2024-03-27 22:23:04 +08:00
" errorCode " varchar ( 255 ) ,
" errorMessage " text ,
2024-04-16 23:35:27 +08:00
" lastUpdatedAt " timestamp with time zone DEFAULT now ( ) ,
CONSTRAINT " user_transcriptionError_pkey " PRIMARY KEY ( " meetingId " , " userId " ) ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2024-03-27 22:23:04 +08:00
) ;
2024-05-02 22:50:19 +08:00
CREATE INDEX " idx_user_transcriptionError_pk_reverse " ON " user_transcriptionError " ( " userId " , " meetingId " ) ;
2024-03-27 22:23:04 +08:00
CREATE INDEX " idx_user_transcriptionError_meetingId " ON " user_transcriptionError " ( " meetingId " ) ;
create view " v_user_transcriptionError " as select * from " user_transcriptionError " ;
2024-02-07 00:26:48 +08:00
create view " v_meeting " as
select " meeting " . * , " user_ended " . " name " as " endedByUserName "
from " meeting "
2024-04-16 23:35:27 +08:00
left join " user " " user_ended " on " user_ended " . " meetingId " = " meeting " . " meetingId " and " user_ended " . " userId " = " meeting " . " endedBy "
2024-02-07 00:26:48 +08:00
;
2024-02-21 01:55:54 +08:00
create view " v_meeting_learningDashboard " as
select " meetingId " , " learningDashboardAccessToken "
from " v_meeting " ;
2024-02-07 00:26:48 +08:00
2023-03-29 20:55:41 +08:00
-- ===================== CHAT TABLES
CREATE TABLE " chat " (
" meetingId " varchar ( 100 ) REFERENCES " meeting " ( " meetingId " ) ON DELETE CASCADE ,
2024-05-02 22:50:19 +08:00
" chatId " varchar ( 100 ) ,
2023-03-29 20:55:41 +08:00
" access " varchar ( 20 ) ,
" createdBy " varchar ( 25 ) ,
2024-05-02 22:50:19 +08:00
CONSTRAINT " chat_pkey " PRIMARY KEY ( " meetingId " , " chatId " )
2023-03-29 20:55:41 +08:00
) ;
2024-05-02 22:50:19 +08:00
CREATE INDEX " idx_chat_pk_reverse " ON " chat " ( " chatId " , " meetingId " ) ;
2023-04-01 04:46:17 +08:00
CREATE INDEX " idx_chat_meetingId " ON " chat " ( " meetingId " ) ;
2023-03-29 20:55:41 +08:00
CREATE TABLE " chat_user " (
" chatId " varchar ( 100 ) ,
" meetingId " varchar ( 100 ) ,
2023-04-06 00:56:22 +08:00
" userId " varchar ( 50 ) ,
2023-09-26 21:20:29 +08:00
" lastSeenAt " timestamp with time zone ,
2023-11-02 03:29:37 +08:00
" startedTypingAt " timestamp with time zone ,
" lastTypingAt " timestamp with time zone ,
2023-04-27 03:19:58 +08:00
" visible " boolean ,
2024-05-02 22:50:19 +08:00
CONSTRAINT " chat_user_pkey " PRIMARY KEY ( " meetingId " , " chatId " , " userId " ) ,
2023-03-29 20:55:41 +08:00
CONSTRAINT chat_fk FOREIGN KEY ( " chatId " , " meetingId " ) REFERENCES " chat " ( " chatId " , " meetingId " ) ON DELETE CASCADE
) ;
2023-05-03 21:10:02 +08:00
2024-05-02 22:50:19 +08:00
CREATE INDEX " idx_chat_user_pk_reverse " ON " chat_user " ( " userId " , " meetingId " , " chatId " ) ;
CREATE INDEX " idx_chat_user_pk_reverse_b " ON " chat_user " ( " chatId " , " meetingId " , " userId " ) ;
CREATE INDEX " idx_chat_user_chatId_visible " ON " chat_user " ( " chatId " , " meetingId " , " userId " ) WHERE " visible " is true ;
CREATE INDEX " idx_chat_user_meetingId_visible " ON " chat_user " ( " meetingId " , " userId " , " chatId " ) WHERE " visible " is true ;
2023-05-03 21:10:02 +08:00
2023-11-02 03:29:37 +08:00
- - TRIGER startedTypingAt
CREATE OR REPLACE FUNCTION " update_chat_user_startedTypingAt_trigger_func " ( ) RETURNS TRIGGER AS $ $
BEGIN
NEW . " startedTypingAt " : = CASE WHEN NEW . " lastTypingAt " IS NULL THEN NULL
WHEN OLD . " lastTypingAt " IS NULL THEN NEW . " lastTypingAt "
WHEN OLD . " lastTypingAt " < NEW . " lastTypingAt " - INTERVAL ' 5 seconds ' THEN NEW . " lastTypingAt "
ELSE OLD . " startedTypingAt "
END ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER " update_chat_user_startedTypingAt_trigger " BEFORE UPDATE OF " lastTypingAt " ON " chat_user "
FOR EACH ROW EXECUTE FUNCTION " update_chat_user_startedTypingAt_trigger_func " ( ) ;
2023-08-08 21:41:16 +08:00
create view " v_chat_user " as select * from " chat_user " ;
2023-11-02 03:29:37 +08:00
CREATE INDEX " idx_chat_user_typing_public " ON " chat_user " ( " meetingId " , " lastTypingAt " )
2023-05-03 20:04:44 +08:00
WHERE " chatId " = ' MAIN-PUBLIC-GROUP-CHAT '
2023-11-02 03:29:37 +08:00
AND " lastTypingAt " is not null ;
2023-05-03 20:04:44 +08:00
2023-11-02 03:29:37 +08:00
CREATE INDEX " idx_chat_user_typing_private " ON " chat_user " ( " meetingId " , " userId " , " chatId " , " lastTypingAt " )
2023-05-03 20:04:44 +08:00
WHERE " chatId " ! = ' MAIN-PUBLIC-GROUP-CHAT '
2023-05-03 21:10:02 +08:00
AND " visible " is true ;
2023-05-03 20:04:44 +08:00
2023-11-02 03:29:37 +08:00
CREATE INDEX " idx_chat_with_user_typing_private " ON " chat_user " ( " meetingId " , " userId " , " chatId " , " lastTypingAt " )
2023-05-03 21:10:02 +08:00
WHERE " chatId " ! = ' MAIN-PUBLIC-GROUP-CHAT '
2023-11-02 03:29:37 +08:00
AND " lastTypingAt " is not null ;
2023-03-29 20:55:41 +08:00
2023-04-06 00:56:22 +08:00
CREATE OR REPLACE VIEW " v_user_typing_public " AS
2023-11-02 03:29:37 +08:00
SELECT " meetingId " , " chatId " , " userId " , " lastTypingAt " , " startedTypingAt " ,
CASE WHEN " lastTypingAt " > current_timestamp - INTERVAL ' 5 seconds ' THEN true ELSE false END AS " isCurrentlyTyping "
2023-04-06 00:56:22 +08:00
FROM chat_user
2023-05-03 20:04:44 +08:00
WHERE " chatId " = ' MAIN-PUBLIC-GROUP-CHAT '
2023-11-02 03:29:37 +08:00
AND " lastTypingAt " is not null ;
2023-04-06 00:56:22 +08:00
2023-04-26 04:12:15 +08:00
CREATE OR REPLACE VIEW " v_user_typing_private " AS
2023-11-02 03:29:37 +08:00
SELECT chat_user . " meetingId " , chat_user . " chatId " , chat_user . " userId " as " queryUserId " , chat_with . " userId " , chat_with . " lastTypingAt " , chat_with . " startedTypingAt " ,
CASE WHEN chat_with . " lastTypingAt " > current_timestamp - INTERVAL ' 5 seconds ' THEN true ELSE false END AS " isCurrentlyTyping "
2023-04-26 04:12:15 +08:00
FROM chat_user
LEFT JOIN " chat_user " chat_with ON chat_with . " meetingId " = chat_user . " meetingId "
2023-04-27 03:19:58 +08:00
AND chat_with . " userId " ! = chat_user . " userId "
2023-05-03 21:10:02 +08:00
AND chat_with . " chatId " = chat_user . " chatId "
2023-11-02 03:29:37 +08:00
AND chat_with . " lastTypingAt " is not null
2023-05-03 20:04:44 +08:00
WHERE chat_user . " chatId " ! = ' MAIN-PUBLIC-GROUP-CHAT '
2023-05-03 21:10:02 +08:00
AND chat_user . " visible " is true ;
2023-04-06 00:56:22 +08:00
2023-03-29 20:55:41 +08:00
CREATE TABLE " chat_message " (
" messageId " varchar ( 100 ) PRIMARY KEY ,
" chatId " varchar ( 100 ) ,
" meetingId " varchar ( 100 ) ,
2024-10-01 22:32:58 +08:00
" correlationId " varchar ( 100 ) , - - create by akka - apps
" messageSequence " integer , - - populated via trigger
2023-03-29 20:55:41 +08:00
" chatEmphasizedText " boolean ,
2023-05-24 21:56:22 +08:00
" message " text ,
" messageType " varchar ( 50 ) ,
2024-10-01 22:32:58 +08:00
" replyToMessageId " varchar ( 100 ) references " chat_message " ( " messageId " ) ,
2023-05-24 21:56:22 +08:00
" messageMetadata " text ,
2023-03-29 20:55:41 +08:00
" senderId " varchar ( 100 ) ,
" senderName " varchar ( 255 ) ,
" senderRole " varchar ( 20 ) ,
2024-10-03 02:18:21 +08:00
" createdAt " timestamp with time zone not null ,
2024-10-03 03:22:01 +08:00
" editedAt " timestamp with time zone ,
2024-10-03 04:33:34 +08:00
" deletedByUserId " varchar ( 100 ) ,
2024-10-03 02:18:21 +08:00
" deletedAt " timestamp with time zone ,
2023-03-29 20:55:41 +08:00
CONSTRAINT chat_fk FOREIGN KEY ( " chatId " , " meetingId " ) REFERENCES " chat " ( " chatId " , " meetingId " ) ON DELETE CASCADE
) ;
2023-04-01 04:46:17 +08:00
CREATE INDEX " idx_chat_message_chatId " ON " chat_message " ( " chatId " , " meetingId " ) ;
2023-03-29 20:55:41 +08:00
2024-10-01 22:32:58 +08:00
- - Trigger to populate the message with its sequence number ( useful to identify the page it lies )
CREATE OR REPLACE FUNCTION " update_chatMessage_messageSequence " ( )
RETURNS TRIGGER AS $ $
BEGIN
SELECT count ( 1 ) + 1 INTO NEW . " messageSequence "
from " chat_message " cm
where cm . " meetingId " = NEW . " meetingId "
and cm . " chatId " = NEW . " chatId "
and cm . " createdAt " < = NEW . " createdAt " ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER " trigger_update_chatMessage_messageSequence "
BEFORE INSERT ON " chat_message "
FOR EACH ROW
EXECUTE FUNCTION " update_chatMessage_messageSequence " ( ) ;
2023-11-02 03:29:37 +08:00
CREATE OR REPLACE FUNCTION " update_chatUser_clear_lastTypingAt_trigger_func " ( ) RETURNS TRIGGER AS $ $
2023-05-03 20:04:44 +08:00
BEGIN
UPDATE " chat_user "
2023-11-02 03:29:37 +08:00
SET " lastTypingAt " = null
2023-05-03 21:10:02 +08:00
WHERE " chatId " = NEW . " chatId " AND " meetingId " = NEW . " meetingId " AND " userId " = NEW . " senderId " ;
2023-05-03 20:04:44 +08:00
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
2023-11-02 03:29:37 +08:00
CREATE TRIGGER " update_chatUser_clear_lastTypingAt_trigger " AFTER INSERT ON chat_message FOR EACH ROW
EXECUTE FUNCTION " update_chatUser_clear_lastTypingAt_trigger_func " ( ) ;
2023-05-03 20:04:44 +08:00
2024-10-03 02:18:21 +08:00
CREATE TABLE " chat_message_history " (
" messageId " varchar ( 100 ) REFERENCES " chat_message " ( " messageId " ) ON DELETE CASCADE ,
" meetingId " varchar ( 100 ) ,
" messageVersionSequence " integer , - - populated via trigger
" message " text ,
2024-10-03 03:22:01 +08:00
" senderId " varchar ( 100 ) ,
" createdAt " timestamp with time zone ,
2024-10-03 02:18:21 +08:00
" movedToHistoryAt " timestamp with time zone default current_timestamp ,
CONSTRAINT chat_message_history_pk PRIMARY KEY ( " messageId " , " messageVersionSequence " )
) ;
CREATE INDEX " chat_message_history_seq_idx " ON " chat_message_history " ( " messageId " , " messageVersionSequence " ) ;
CREATE OR REPLACE VIEW " v_chat_message_history " AS SELECT * FROM " chat_message_history " ;
CREATE OR REPLACE FUNCTION " update_chat_message_history_trigger_func " ( )
RETURNS TRIGGER AS $ $
BEGIN
2024-10-03 03:22:01 +08:00
IF NEW . " message " IS DISTINCT FROM OLD . " message " THEN
insert into " chat_message_history " ( " messageId " , " meetingId " , " messageVersionSequence " , " message " , " senderId " , " createdAt " )
2024-10-03 02:18:21 +08:00
values ( OLD . " messageId " ,
OLD . " meetingId " ,
( select count ( 1 ) from " chat_message_history " prev where prev . " messageId " = OLD . " messageId " ) ,
OLD . " message " ,
2024-10-03 03:22:01 +08:00
OLD . " senderId " ,
coalesce ( OLD . " editedAt " , OLD . " createdAt " )
2024-10-03 02:18:21 +08:00
) ;
END IF ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER " update_chat_message_history_trigger " BEFORE UPDATE OF " message " ON " chat_message "
FOR EACH ROW EXECUTE FUNCTION " update_chat_message_history_trigger_func " ( ) ;
2023-03-29 20:55:41 +08:00
CREATE OR REPLACE VIEW " v_chat " AS
2023-04-03 21:46:47 +08:00
SELECT " user " . " userId " ,
2023-04-27 03:19:58 +08:00
case when " user " . " userId " = " chat " . " createdBy " then true else false end " amIOwner " ,
2023-03-29 20:55:41 +08:00
chat . " meetingId " ,
chat . " chatId " ,
2023-04-27 03:19:58 +08:00
cu . " visible " ,
2023-03-29 23:06:48 +08:00
chat_with . " userId " AS " participantId " ,
2023-03-29 20:55:41 +08:00
count ( DISTINCT cm . " messageId " ) " totalMessages " ,
2023-09-26 21:20:29 +08:00
sum ( CASE WHEN cm . " senderId " ! = " user " . " userId "
and cm . " createdAt " < current_timestamp - ' 2 seconds ' : : interval - - set a delay while user send lastSeenAt
and cm . " createdAt " > coalesce ( cu . " lastSeenAt " , " user " . " registeredAt " ) THEN 1 ELSE 0 end ) " totalUnread " ,
2023-06-30 20:52:11 +08:00
cu . " lastSeenAt " ,
2023-04-06 00:56:22 +08:00
CASE WHEN chat . " access " = ' PUBLIC_ACCESS ' THEN true ELSE false end public
2023-03-29 20:55:41 +08:00
FROM " user "
2024-05-02 22:19:39 +08:00
JOIN " chat_user " cu ON cu . " meetingId " = " user " . " meetingId " AND cu . " userId " = " user " . " userId "
2023-04-06 00:56:22 +08:00
- - now it will always add chat_user for public chat onUserJoin
- - JOIN " chat " ON " user " . " meetingId " = chat . " meetingId " AND ( cu . " chatId " = chat . " chatId " OR chat . " chatId " = ' MAIN-PUBLIC-GROUP-CHAT ' )
JOIN " chat " ON " user " . " meetingId " = chat . " meetingId " AND cu . " chatId " = chat . " chatId "
2024-04-16 23:35:27 +08:00
LEFT JOIN " chat_user " chat_with ON chat_with . " meetingId " = chat . " meetingId " AND
chat_with . " chatId " = chat . " chatId " AND
2024-05-02 22:19:39 +08:00
chat_with . " userId " ! = cu . " userId " AND
chat_with . " chatId " ! = ' MAIN-PUBLIC-GROUP-CHAT '
2024-04-16 23:35:27 +08:00
LEFT JOIN chat_message cm ON cm . " meetingId " = chat . " meetingId " AND
cm . " chatId " = chat . " chatId "
2023-04-27 03:19:58 +08:00
WHERE cu . " visible " is true
2023-06-30 20:52:11 +08:00
GROUP BY " user " . " userId " , chat . " meetingId " , chat . " chatId " , cu . " visible " , cu . " lastSeenAt " , chat_with . " userId " ;
2023-03-29 20:55:41 +08:00
2024-05-02 22:19:39 +08:00
create index idx_v_chat_with on chat_user ( " meetingId " , " chatId " , " userId " ) where " chatId " ! = ' MAIN-PUBLIC-GROUP-CHAT ' ;
2023-03-29 20:55:41 +08:00
CREATE OR REPLACE VIEW " v_chat_message_public " AS
2023-09-26 21:20:29 +08:00
SELECT cm . *
2023-03-29 20:55:41 +08:00
FROM chat_message cm
WHERE cm . " chatId " = ' MAIN-PUBLIC-GROUP-CHAT ' ;
CREATE OR REPLACE VIEW " v_chat_message_private " AS
2024-04-16 23:35:27 +08:00
SELECT cu . " meetingId " ,
cu . " userId " ,
cm . " messageId " ,
cm . " chatId " ,
cm . " correlationId " ,
2024-10-01 22:32:58 +08:00
cm . " messageSequence " ,
2024-04-16 23:35:27 +08:00
cm . " chatEmphasizedText " ,
cm . " message " ,
cm . " messageType " ,
2024-10-01 22:32:58 +08:00
cm . " replyToMessageId " ,
2024-04-16 23:35:27 +08:00
cm . " messageMetadata " ,
cm . " senderId " ,
cm . " senderName " ,
cm . " senderRole " ,
2024-07-23 00:01:24 +08:00
cm . " createdAt " ,
2024-10-03 03:22:01 +08:00
cm . " editedAt " ,
2024-10-03 04:33:34 +08:00
cm . " deletedByUserId " ,
2024-10-03 02:18:21 +08:00
cm . " deletedAt " ,
2024-07-23 00:01:24 +08:00
CASE WHEN chat_with . " lastSeenAt " > = cm . " createdAt " THEN true ELSE false end " recipientHasSeen "
2023-03-29 20:55:41 +08:00
FROM chat_message cm
2023-04-14 21:58:37 +08:00
JOIN chat_user cu ON cu . " meetingId " = cm . " meetingId " AND cu . " chatId " = cm . " chatId "
2024-07-23 00:01:24 +08:00
LEFT JOIN " chat_user " chat_with ON chat_with . " meetingId " = cm . " meetingId "
AND chat_with . " chatId " = cm . " chatId "
AND chat_with . " userId " ! = cu . " userId "
2023-04-14 21:58:37 +08:00
WHERE cm . " chatId " ! = ' MAIN-PUBLIC-GROUP-CHAT ' ;
2023-03-29 20:55:41 +08:00
2024-10-04 01:34:24 +08:00
CREATE TABLE " chat_message_reaction " (
" meetingId " varchar ( 100 ) ,
" messageId " varchar ( 100 ) REFERENCES " chat_message " ( " messageId " ) ON DELETE CASCADE ,
" userId " varchar ( 100 ) not null ,
" reactionEmoji " varchar ( 25 ) ,
2024-10-21 19:28:43 +08:00
" reactionEmojiId " varchar ( 50 ) ,
2024-10-04 01:34:24 +08:00
" createdAt " timestamp with time zone ,
CONSTRAINT chat_message_reaction_pk PRIMARY KEY ( " messageId " , " userId " , " reactionEmoji " ) ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
) ;
CREATE INDEX " chat_message_reaction_meeting_message_idx " ON " chat_message_reaction " ( " meetingId " , " messageId " ) ;
CREATE INDEX " chat_message_reaction_meeting_message_idx_rev " ON " chat_message_reaction " ( " messageId " , " meetingId " ) ;
CREATE OR REPLACE VIEW " v_chat_message_reaction " AS SELECT * FROM " chat_message_reaction " ;
2023-04-01 04:46:17 +08:00
- - = = = = = = = = = = = = Presentation / Annotation
2023-03-29 20:55:41 +08:00
2023-04-01 04:46:17 +08:00
CREATE TABLE " pres_presentation " (
" presentationId " varchar ( 100 ) PRIMARY KEY ,
" meetingId " varchar ( 100 ) REFERENCES " meeting " ( " meetingId " ) ON DELETE CASCADE ,
2023-11-01 22:38:19 +08:00
" uploadUserId " varchar ( 100 ) ,
" uploadTemporaryId " varchar ( 100 ) , - - generated by UI
" uploadToken " varchar ( 100 ) , - - generated by Akka - apps , used for upload POST
2023-10-03 03:51:53 +08:00
" name " varchar ( 500 ) ,
" filenameConverted " varchar ( 500 ) ,
" isDefault " boolean ,
2023-04-01 04:46:17 +08:00
" current " boolean ,
2023-10-17 22:03:46 +08:00
" removable " boolean ,
2023-04-01 04:46:17 +08:00
" downloadable " boolean ,
2023-10-12 02:27:08 +08:00
" downloadFileExtension " varchar ( 25 ) ,
2023-09-29 23:15:36 +08:00
" downloadFileUri " varchar ( 500 ) ,
2023-10-17 22:03:46 +08:00
" uploadInProgress " boolean ,
2023-09-22 03:20:48 +08:00
" uploadCompleted " boolean ,
2023-10-17 22:03:46 +08:00
" uploadErrorMsgKey " varchar ( 100 ) ,
" uploadErrorDetailsJson " jsonb ,
" totalPages " integer ,
" exportToChatStatus " varchar ( 25 ) ,
" exportToChatCurrentPage " integer ,
2023-11-01 22:38:19 +08:00
" exportToChatHasError " boolean ,
" createdAt " timestamp with time zone DEFAULT now ( )
2023-04-01 04:46:17 +08:00
) ;
CREATE INDEX " idx_pres_presentation_meetingId " ON " pres_presentation " ( " meetingId " ) ;
2023-06-26 20:46:54 +08:00
CREATE INDEX " idx_pres_presentation_meetingId_curr " ON " pres_presentation " ( " meetingId " ) where " current " is true ;
2023-11-08 00:47:44 +08:00
CREATE INDEX " idx_pres_presentation_meetingId_uploadUserId " ON " pres_presentation " ( " meetingId " , " uploadUserId " ) ;
2023-06-26 20:46:54 +08:00
2023-04-06 00:56:22 +08:00
CREATE TABLE " pres_page " (
2023-04-01 04:46:17 +08:00
" pageId " varchar ( 100 ) PRIMARY KEY ,
" presentationId " varchar ( 100 ) REFERENCES " pres_presentation " ( " presentationId " ) ON DELETE CASCADE ,
" num " integer ,
2023-10-17 22:03:46 +08:00
" urlsJson " jsonb ,
2023-09-29 23:15:36 +08:00
" content " TEXT ,
2023-06-26 20:46:54 +08:00
" slideRevealed " boolean default false ,
2023-04-01 04:46:17 +08:00
" current " boolean ,
" xOffset " NUMERIC ,
" yOffset " NUMERIC ,
" widthRatio " NUMERIC ,
2023-07-26 21:53:15 +08:00
" heightRatio " NUMERIC ,
" width " NUMERIC ,
2023-07-28 03:10:51 +08:00
" height " NUMERIC ,
" viewBoxWidth " NUMERIC ,
2023-08-04 04:14:38 +08:00
" viewBoxHeight " NUMERIC ,
" maxImageWidth " integer ,
2023-09-22 03:20:48 +08:00
" maxImageHeight " integer ,
2024-06-14 21:58:32 +08:00
" uploadCompleted " boolean ,
2024-07-06 04:09:19 +08:00
" infiniteWhiteboard " boolean
2023-04-01 04:46:17 +08:00
) ;
CREATE INDEX " idx_pres_page_presentationId " ON " pres_page " ( " presentationId " ) ;
2023-06-26 20:46:54 +08:00
CREATE INDEX " idx_pres_page_presentationId_curr " ON " pres_page " ( " presentationId " ) where " current " is true ;
2023-09-22 03:20:48 +08:00
CREATE OR REPLACE VIEW public . v_pres_presentation AS
SELECT pres_presentation . " meetingId " ,
pres_presentation . " presentationId " ,
2023-10-03 03:51:53 +08:00
pres_presentation . " name " ,
pres_presentation . " filenameConverted " ,
pres_presentation . " isDefault " ,
2023-09-22 03:20:48 +08:00
pres_presentation . " current " ,
pres_presentation . " downloadable " ,
2023-10-12 02:27:08 +08:00
pres_presentation . " downloadFileExtension " ,
2023-09-29 23:15:36 +08:00
pres_presentation . " downloadFileUri " ,
2023-09-22 03:20:48 +08:00
pres_presentation . " removable " ,
2023-11-01 22:38:19 +08:00
pres_presentation . " uploadTemporaryId " ,
2023-10-17 22:03:46 +08:00
pres_presentation . " uploadInProgress " ,
2023-09-22 03:20:48 +08:00
pres_presentation . " uploadCompleted " ,
2023-10-17 22:03:46 +08:00
pres_presentation . " totalPages " ,
( SELECT count ( * )
FROM pres_page
WHERE pres_page . " presentationId " = pres_presentation . " presentationId "
AND " uploadCompleted " is true
) as " totalPagesUploaded " ,
pres_presentation . " uploadErrorMsgKey " ,
pres_presentation . " uploadErrorDetailsJson " ,
case when pres_presentation . " exportToChatStatus " is not null
and pres_presentation . " exportToChatStatus " ! = ' EXPORTED '
and pres_presentation . " exportToChatHasError " is not true
then true else false end " exportToChatInProgress " ,
pres_presentation . " exportToChatStatus " ,
pres_presentation . " exportToChatCurrentPage " ,
2023-11-01 22:38:19 +08:00
pres_presentation . " exportToChatHasError " ,
pres_presentation . " createdAt "
2023-09-22 03:20:48 +08:00
FROM pres_presentation ;
2023-06-26 20:46:54 +08:00
CREATE OR REPLACE VIEW public . v_pres_page AS
SELECT pres_presentation . " meetingId " ,
pres_page . " presentationId " ,
pres_page . " pageId " ,
pres_page . num ,
2023-10-17 22:03:46 +08:00
pres_page . " urlsJson " ,
2023-09-29 23:15:36 +08:00
pres_page . content ,
2023-06-26 20:46:54 +08:00
pres_page . " slideRevealed " ,
CASE WHEN pres_presentation . " current " IS TRUE AND pres_page . " current " IS TRUE THEN true ELSE false END AS " isCurrentPage " ,
pres_page . " xOffset " ,
pres_page . " yOffset " ,
pres_page . " widthRatio " ,
2023-07-29 02:01:53 +08:00
pres_page . " heightRatio " ,
pres_page . " width " ,
pres_page . " height " ,
2023-08-04 04:14:38 +08:00
pres_page . " viewBoxWidth " ,
pres_page . " viewBoxHeight " ,
2023-08-04 22:02:06 +08:00
( pres_page . " width " * LEAST ( pres_page . " maxImageWidth " / pres_page . " width " , pres_page . " maxImageHeight " / pres_page . " height " ) ) AS " scaledWidth " ,
( pres_page . " height " * LEAST ( pres_page . " maxImageWidth " / pres_page . " width " , pres_page . " maxImageHeight " / pres_page . " height " ) ) AS " scaledHeight " ,
( pres_page . " width " * pres_page . " widthRatio " / 100 * LEAST ( pres_page . " maxImageWidth " / pres_page . " width " , pres_page . " maxImageHeight " / pres_page . " height " ) ) AS " scaledViewBoxWidth " ,
2023-09-22 03:20:48 +08:00
( pres_page . " height " * pres_page . " heightRatio " / 100 * LEAST ( pres_page . " maxImageWidth " / pres_page . " width " , pres_page . " maxImageHeight " / pres_page . " height " ) ) AS " scaledViewBoxHeight " ,
2024-06-14 21:58:32 +08:00
pres_page . " uploadCompleted " ,
2024-07-06 04:09:19 +08:00
pres_page . " infiniteWhiteboard "
2023-06-26 20:46:54 +08:00
FROM pres_page
JOIN pres_presentation ON pres_presentation . " presentationId " = pres_page . " presentationId " ;
CREATE OR REPLACE VIEW public . v_pres_page_curr AS
SELECT pres_presentation . " meetingId " ,
pres_page . " presentationId " ,
pres_page . " pageId " ,
2023-10-03 03:51:53 +08:00
pres_presentation . " name " as " presentationName " ,
pres_presentation . " filenameConverted " as " presentationFilenameConverted " ,
pres_presentation . " isDefault " as " isDefaultPresentation " ,
2023-06-26 20:46:54 +08:00
pres_presentation . " downloadable " ,
2023-10-12 02:27:08 +08:00
case when pres_presentation . " downloadable " then pres_presentation . " downloadFileExtension " else null end " downloadFileExtension " ,
2023-09-29 23:15:36 +08:00
case when pres_presentation . " downloadable " then pres_presentation . " downloadFileUri " else null end " downloadFileUri " ,
2023-06-26 20:46:54 +08:00
pres_presentation . " removable " ,
2023-10-17 22:03:46 +08:00
pres_presentation . " totalPages " ,
2023-06-26 20:46:54 +08:00
pres_page . num ,
2023-10-17 22:03:46 +08:00
pres_page . " urlsJson " ,
2023-09-29 23:15:36 +08:00
pres_page . content ,
2023-06-26 20:46:54 +08:00
pres_page . " slideRevealed " ,
CASE WHEN pres_presentation . " current " IS TRUE AND pres_page . " current " IS TRUE THEN true ELSE false END AS " isCurrentPage " ,
pres_page . " xOffset " ,
pres_page . " yOffset " ,
pres_page . " widthRatio " ,
2023-07-29 02:01:53 +08:00
pres_page . " heightRatio " ,
pres_page . " width " ,
pres_page . " height " ,
pres_page . " viewBoxWidth " ,
2023-08-04 22:02:06 +08:00
pres_page . " viewBoxHeight " ,
( pres_page . " width " * LEAST ( pres_page . " maxImageWidth " / pres_page . " width " , pres_page . " maxImageHeight " / pres_page . " height " ) ) AS " scaledWidth " ,
( pres_page . " height " * LEAST ( pres_page . " maxImageWidth " / pres_page . " width " , pres_page . " maxImageHeight " / pres_page . " height " ) ) AS " scaledHeight " ,
( pres_page . " width " * pres_page . " widthRatio " / 100 * LEAST ( pres_page . " maxImageWidth " / pres_page . " width " , pres_page . " maxImageHeight " / pres_page . " height " ) ) AS " scaledViewBoxWidth " ,
2024-06-14 21:58:32 +08:00
( pres_page . " height " * pres_page . " heightRatio " / 100 * LEAST ( pres_page . " maxImageWidth " / pres_page . " width " , pres_page . " maxImageHeight " / pres_page . " height " ) ) AS " scaledViewBoxHeight " ,
2024-07-06 04:09:19 +08:00
pres_page . " infiniteWhiteboard "
2023-06-26 20:46:54 +08:00
FROM pres_presentation
JOIN pres_page ON pres_presentation . " presentationId " = pres_page . " presentationId " AND pres_page . " current " IS TRUE
and pres_presentation . " current " IS TRUE ;
2023-04-01 04:46:17 +08:00
2023-04-06 00:56:22 +08:00
CREATE TABLE " pres_annotation " (
2023-04-01 04:46:17 +08:00
" annotationId " varchar ( 100 ) PRIMARY KEY ,
" pageId " varchar ( 100 ) REFERENCES " pres_page " ( " pageId " ) ON DELETE CASCADE ,
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) ,
2023-04-06 00:56:22 +08:00
" userId " varchar ( 50 ) ,
2023-04-01 04:46:17 +08:00
" annotationInfo " TEXT ,
2023-04-03 21:46:47 +08:00
" lastHistorySequence " integer ,
2023-08-08 21:53:04 +08:00
" lastUpdatedAt " timestamp with time zone DEFAULT now ( )
2023-04-01 04:46:17 +08:00
) ;
CREATE INDEX " idx_pres_annotation_pageId " ON " pres_annotation " ( " pageId " ) ;
2023-04-04 04:23:30 +08:00
CREATE INDEX " idx_pres_annotation_updatedAt " ON " pres_annotation " ( " pageId " , " lastUpdatedAt " ) ;
2024-05-02 22:50:19 +08:00
create index " idx_pres_annotation_user_meeting " on " pres_annotation " ( " userId " , " meetingId " ) ;
2023-04-01 04:46:17 +08:00
2023-04-06 00:56:22 +08:00
CREATE TABLE " pres_annotation_history " (
2023-04-01 04:46:17 +08:00
" sequence " serial PRIMARY KEY ,
" annotationId " varchar ( 100 ) ,
" pageId " varchar ( 100 ) REFERENCES " pres_page " ( " pageId " ) ON DELETE CASCADE ,
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) ,
2023-04-06 00:56:22 +08:00
" userId " varchar ( 50 ) ,
2023-04-01 04:46:17 +08:00
" annotationInfo " TEXT
2023-08-08 21:53:04 +08:00
-- "lastUpdatedAt" timestamp with time zone DEFAULT now()
2023-04-01 04:46:17 +08:00
) ;
CREATE INDEX " idx_pres_annotation_history_pageId " ON " pres_annotation " ( " pageId " ) ;
2024-05-02 22:50:19 +08:00
create index " idx_pres_annotation_history_user_meeting " on " pres_annotation_history " ( " userId " , " meetingId " ) ;
2023-04-01 04:46:17 +08:00
2023-04-06 00:56:22 +08:00
CREATE VIEW " v_pres_annotation_curr " AS
2024-04-16 23:35:27 +08:00
SELECT p . " meetingId " , pp . " presentationId " , pa . " annotationId " , pa . " pageId " , pa . " userId " , pa . " annotationInfo " , pa . " lastHistorySequence " , pa . " lastUpdatedAt "
2023-04-01 04:46:17 +08:00
FROM pres_presentation p
JOIN pres_page pp ON pp . " presentationId " = p . " presentationId "
JOIN pres_annotation pa ON pa . " pageId " = pp . " pageId "
2023-04-06 00:56:22 +08:00
WHERE p . " current " IS true
AND pp . " current " IS true ;
2023-04-01 04:46:17 +08:00
2023-04-06 00:56:22 +08:00
CREATE VIEW " v_pres_annotation_history_curr " AS
2024-04-16 23:35:27 +08:00
SELECT p . " meetingId " , pp . " presentationId " , pah . " pageId " , pah . " userId " , pah . " annotationId " , pah . " annotationInfo " , pah . " sequence "
2023-04-01 04:46:17 +08:00
FROM pres_presentation p
JOIN pres_page pp ON pp . " presentationId " = p . " presentationId "
JOIN pres_annotation_history pah ON pah . " pageId " = pp . " pageId "
2023-04-06 00:56:22 +08:00
WHERE p . " current " IS true
AND pp . " current " IS true ;
2023-04-01 04:46:17 +08:00
CREATE TABLE " pres_page_writers " (
" pageId " varchar ( 100 ) REFERENCES " pres_page " ( " pageId " ) ON DELETE CASCADE ,
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) ,
" userId " varchar ( 50 ) ,
2023-04-01 04:46:17 +08:00
" changedModeOn " bigint ,
2024-04-16 23:35:27 +08:00
CONSTRAINT " pres_page_writers_pkey " PRIMARY KEY ( " pageId " , " meetingId " , " userId " ) ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2023-04-01 04:46:17 +08:00
) ;
2024-05-02 22:50:19 +08:00
create index " idx_pres_page_writers_userID " on " pres_page_writers " ( " meetingId " , " userId " , " pageId " ) ;
create index " idx_pres_page_writers_userID_rev " on " pres_page_writers " ( " userId " , " meetingId " , " pageId " ) ;
2023-04-01 04:46:17 +08:00
CREATE OR REPLACE VIEW " v_pres_page_writers " AS
SELECT
" pres_presentation " . " presentationId " ,
" pres_page_writers " . * ,
2023-04-06 00:56:22 +08:00
CASE WHEN pres_presentation . " current " IS true AND pres_page . " current " IS true THEN true ELSE false END AS " isCurrentPage "
2023-04-01 04:46:17 +08:00
FROM " pres_page_writers "
JOIN " pres_page " ON " pres_page " . " pageId " = " pres_page_writers " . " pageId "
JOIN " pres_presentation " ON " pres_presentation " . " presentationId " = " pres_page " . " presentationId " ;
2023-11-08 00:47:44 +08:00
CREATE OR REPLACE VIEW " v_pres_presentation_uploadToken " AS
SELECT " meetingId " , " presentationId " , " uploadUserId " , " uploadTemporaryId " , " uploadToken "
FROM pres_presentation pp
WHERE " uploadInProgress " IS FALSE
AND " uploadCompleted " IS FALSE ;
2023-04-20 20:49:16 +08:00
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
-- Triggers to automatically control "user" flag "hasDrawPermissionOnCurrentPage"
CREATE OR REPLACE FUNCTION " update_user_hasDrawPermissionOnCurrentPage " ( " p_userId " varchar DEFAULT NULL , " p_meetingId " varchar DEFAULT NULL )
RETURNS VOID AS $ $
DECLARE
where_clause TEXT : = ' ' ;
BEGIN
IF " p_userId " IS NOT NULL THEN
where_clause : = format ( ' AND "userId" = %L ' , " p_userId " ) ;
END IF ;
IF " p_meetingId " IS NOT NULL THEN
where_clause : = format ( ' %s AND "meetingId" = %L ' , where_clause , " p_meetingId " ) ;
END IF ;
IF where_clause < > ' ' THEN
where_clause : = substring ( where_clause from 6 ) ;
EXECUTE format ( ' UPDATE "user"
SET " hasDrawPermissionOnCurrentPage " =
CASE WHEN presenter THEN TRUE
WHEN EXISTS (
SELECT 1 FROM " v_pres_page_writers " v
2024-04-16 23:35:27 +08:00
WHERE v . " meetingId " = " user " . " meetingId "
AND v . " userId " = " user " . " userId "
2023-04-20 20:49:16 +08:00
AND v . " isCurrentPage " IS TRUE
) THEN TRUE
ELSE FALSE
END WHERE % s ' , where_clause);
ELSE
RAISE EXCEPTION ' No params provided ' ;
END IF ;
END ;
$ $ LANGUAGE plpgsql ;
-- user (on update presenter)
CREATE OR REPLACE FUNCTION update_user_presenter_trigger_func ( ) RETURNS TRIGGER AS $ $
BEGIN
IF OLD . " presenter " < > NEW . " presenter " THEN
2024-04-16 23:35:27 +08:00
PERFORM " update_user_hasDrawPermissionOnCurrentPage " ( NEW . " userId " , NEW . " meetingId " ) ;
2023-04-20 20:49:16 +08:00
END IF ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER update_user_presenter_trigger AFTER UPDATE OF " presenter " ON " user "
FOR EACH ROW EXECUTE FUNCTION update_user_presenter_trigger_func ( ) ;
-- pres_presentation (on update current)
CREATE OR REPLACE FUNCTION update_pres_presentation_current_trigger_func ( ) RETURNS TRIGGER AS $ $
BEGIN
IF OLD . " current " < > NEW . " current " THEN
PERFORM " update_user_hasDrawPermissionOnCurrentPage " ( NULL , NEW . " meetingId " ) ;
END IF ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER update_pres_presentation_current_trigger AFTER UPDATE OF " current " ON " pres_presentation "
FOR EACH ROW EXECUTE FUNCTION update_pres_presentation_current_trigger_func ( ) ;
-- pres_page (on update current)
CREATE OR REPLACE FUNCTION update_pres_page_current_trigger_func ( )
RETURNS TRIGGER AS $ $
BEGIN
IF OLD . " current " < > NEW . " current " THEN
PERFORM " update_user_hasDrawPermissionOnCurrentPage " ( NULL , pres_presentation . " meetingId " )
FROM pres_presentation
WHERE " presentationId " = NEW . " presentationId " ;
END IF ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER update_pres_page_current_trigger AFTER UPDATE OF " current " ON " pres_page "
FOR EACH ROW EXECUTE FUNCTION update_pres_page_current_trigger_func ( ) ;
-- pres_page_writers (on insert, update or delete)
CREATE OR REPLACE FUNCTION ins_upd_del_pres_page_writers_trigger_func ( )
RETURNS TRIGGER AS $ $
BEGIN
IF TG_OP = ' UPDATE ' or TG_OP = ' INSERT ' THEN
2024-04-16 23:35:27 +08:00
PERFORM " update_user_hasDrawPermissionOnCurrentPage " ( NEW . " userId " , NEW . " meetingId " ) ;
2023-04-20 20:49:16 +08:00
ELSIF TG_OP = ' DELETE ' THEN
2024-04-16 23:35:27 +08:00
PERFORM " update_user_hasDrawPermissionOnCurrentPage " ( OLD . " userId " , NEW . " meetingId " ) ;
2023-04-20 20:49:16 +08:00
END IF ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER ins_upd_del_pres_page_writers_trigger AFTER INSERT OR UPDATE OR DELETE ON " pres_page_writers "
FOR EACH ROW EXECUTE FUNCTION ins_upd_del_pres_page_writers_trigger_func ( ) ;
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
2023-04-04 04:23:30 +08:00
CREATE TABLE " pres_page_cursor " (
" pageId " varchar ( 100 ) REFERENCES " pres_page " ( " pageId " ) ON DELETE CASCADE ,
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) ,
" userId " varchar ( 50 ) ,
2023-04-04 04:23:30 +08:00
" xPercent " numeric ,
" yPercent " numeric ,
2023-08-08 21:53:04 +08:00
" lastUpdatedAt " timestamp with time zone DEFAULT now ( ) ,
2024-04-16 23:35:27 +08:00
CONSTRAINT " pres_page_cursor_pkey " PRIMARY KEY ( " pageId " , " meetingId " , " userId " ) ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2023-04-04 04:23:30 +08:00
) ;
create index " idx_pres_page_cursor_pageId " on " pres_page_cursor " ( " pageId " ) ;
2024-04-16 23:35:27 +08:00
create index " idx_pres_page_cursor_userID " on " pres_page_cursor " ( " meetingId " , " userId " ) ;
2024-05-02 22:50:19 +08:00
create index " idx_pres_page_cursor_userID_rev " on " pres_page_cursor " ( " userId " , " meetingId " ) ;
2023-04-04 04:23:30 +08:00
create index " idx_pres_page_cursor_lastUpdatedAt " on " pres_page_cursor " ( " pageId " , " lastUpdatedAt " ) ;
2023-04-06 00:56:22 +08:00
CREATE VIEW " v_pres_page_cursor " AS
2024-04-16 23:35:27 +08:00
SELECT pres_page . " presentationId " , c . * ,
2023-04-06 00:56:22 +08:00
CASE WHEN pres_presentation . " current " IS true AND pres_page . " current " IS true THEN true ELSE false END AS " isCurrentPage "
2023-04-04 04:23:30 +08:00
FROM pres_page_cursor c
JOIN pres_page ON pres_page . " pageId " = c . " pageId "
JOIN pres_presentation ON pres_presentation . " presentationId " = pres_page . " presentationId " ;
2023-04-01 04:46:17 +08:00
2023-05-20 00:47:00 +08:00
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
- - -- Polls
CREATE TABLE " poll " (
" pollId " varchar ( 100 ) PRIMARY KEY ,
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) ,
" ownerId " varchar ( 100 ) ,
2023-05-20 00:47:00 +08:00
" questionText " TEXT ,
" type " varchar ( 30 ) ,
" secret " boolean ,
" multipleResponses " boolean ,
" ended " boolean ,
" published " boolean ,
2024-01-18 22:23:38 +08:00
" publishedAt " timestamp with time zone ,
2024-04-16 23:35:27 +08:00
" createdAt " timestamp with time zone not null default current_timestamp ,
FOREIGN KEY ( " meetingId " , " ownerId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2023-05-20 00:47:00 +08:00
) ;
CREATE INDEX " idx_poll_meetingId " ON " poll " ( " meetingId " ) ;
2024-04-16 23:35:27 +08:00
CREATE INDEX " idx_poll_ownerId " ON " poll " ( " meetingId " , " ownerId " ) ;
2023-05-20 00:47:00 +08:00
CREATE INDEX " idx_poll_meetingId_active " ON " poll " ( " meetingId " ) where ended is false ;
CREATE INDEX " idx_poll_meetingId_published " ON " poll " ( " meetingId " ) where published is true ;
CREATE TABLE " poll_option " (
" pollId " varchar ( 100 ) REFERENCES " poll " ( " pollId " ) ON DELETE CASCADE ,
" optionId " integer ,
" optionDesc " TEXT ,
CONSTRAINT " poll_option_pkey " PRIMARY KEY ( " pollId " , " optionId " )
) ;
CREATE INDEX " idx_poll_option_pollId " ON " poll_option " ( " pollId " ) ;
CREATE TABLE " poll_response " (
" pollId " varchar ( 100 ) ,
" optionId " integer ,
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) ,
" userId " varchar ( 100 ) ,
FOREIGN KEY ( " pollId " , " optionId " ) REFERENCES " poll_option " ( " pollId " , " optionId " ) ON DELETE CASCADE ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2023-05-20 00:47:00 +08:00
) ;
CREATE INDEX " idx_poll_response_pollId " ON " poll_response " ( " pollId " ) ;
2024-04-16 23:35:27 +08:00
CREATE INDEX " idx_poll_response_userId " ON " poll_response " ( " meetingId " , " userId " ) ;
2024-05-02 22:50:19 +08:00
CREATE INDEX " idx_poll_response_userId_reverse " ON " poll_response " ( " userId " , " meetingId " ) ;
2024-04-16 23:35:27 +08:00
CREATE INDEX " idx_poll_response_pollId_userId " ON " poll_response " ( " pollId " , " meetingId " , " userId " ) ;
2023-05-20 00:47:00 +08:00
2023-05-23 20:09:38 +08:00
CREATE OR REPLACE VIEW " v_poll_response " AS
2023-05-20 00:47:00 +08:00
SELECT
poll . " meetingId " ,
poll . " pollId " ,
poll . " type " ,
poll . " questionText " ,
2024-04-16 23:35:27 +08:00
poll . " meetingId " AS " pollOwnerMeetingId " ,
2023-05-20 00:47:00 +08:00
poll . " ownerId " AS " pollOwnerId " ,
poll . published ,
o . " optionId " ,
o . " optionDesc " ,
count ( r . " optionId " ) AS " optionResponsesCount " ,
sum ( count ( r . " optionId " ) ) OVER ( partition by poll . " pollId " ) " pollResponsesCount "
FROM poll
JOIN poll_option o ON o . " pollId " = poll . " pollId "
LEFT JOIN poll_response r ON r . " pollId " = poll . " pollId " AND o . " optionId " = r . " optionId "
GROUP BY poll . " pollId " , o . " optionId " , o . " optionDesc "
ORDER BY poll . " pollId " ;
2023-05-23 20:09:38 +08:00
CREATE VIEW " v_poll_user " AS
2023-05-20 00:47:00 +08:00
SELECT
2024-04-16 23:35:27 +08:00
poll . " meetingId " AS " pollOwnerMeetingId " ,
poll . " ownerId " AS " pollOwnerId " ,
u . " meetingId " ,
u . " userId " ,
2023-05-20 00:47:00 +08:00
poll . " pollId " ,
poll . " type " ,
poll . " questionText " ,
array_remove ( array_agg ( o . " optionId " ) , NULL ) AS " optionIds " ,
array_remove ( array_agg ( o . " optionDesc " ) , NULL ) AS " optionDescIds " ,
CASE WHEN count ( o . " optionId " ) > 0 THEN TRUE ELSE FALSE end responded
FROM poll
JOIN v_user u ON u . " meetingId " = poll . " meetingId " AND " isDialIn " IS FALSE AND presenter IS FALSE
LEFT JOIN poll_response r ON r . " pollId " = poll . " pollId " AND r . " userId " = u . " userId "
LEFT JOIN poll_option o ON o . " pollId " = r . " pollId " AND o . " optionId " = r . " optionId "
2024-10-18 04:44:07 +08:00
WHERE u . " bot " IS FALSE
2024-04-16 23:35:27 +08:00
GROUP BY poll . " pollId " , u . " meetingId " , u . " userId " ;
2023-05-20 00:47:00 +08:00
2023-05-23 20:09:38 +08:00
CREATE VIEW " v_poll " AS SELECT * FROM " poll " ;
2023-05-20 00:47:00 +08:00
CREATE VIEW v_poll_option AS
SELECT poll . " meetingId " , poll . " pollId " , o . " optionId " , o . " optionDesc "
FROM poll_option o
JOIN poll using ( " pollId " )
WHERE poll . " type " ! = ' R- ' ;
2023-05-23 20:09:38 +08:00
2024-01-23 02:51:33 +08:00
create view " v_poll_user_current " as
2024-04-16 23:35:27 +08:00
select " user " . " meetingId " , " user " . " userId " , " poll " . " pollId " , case when count ( pr . * ) > 0 then true else false end as responded
2024-01-23 02:51:33 +08:00
from " user "
join " poll " on " poll " . " meetingId " = " user " . " meetingId "
2024-04-16 23:35:27 +08:00
left join " poll_response " pr on pr . " meetingId " = " user " . " meetingId " and
pr . " userId " = " user " . " userId " and
pr . " pollId " = " poll " . " pollId "
group by " user " . " meetingId " , " user " . " userId " , " poll " . " pollId " ;
2024-01-23 02:51:33 +08:00
2023-05-23 20:09:38 +08:00
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
- - - - External video
2023-09-07 20:16:30 +08:00
create table " externalVideo " (
2023-05-23 20:09:38 +08:00
" externalVideoId " varchar ( 100 ) primary key ,
" meetingId " varchar ( 100 ) REFERENCES " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" externalVideoUrl " varchar ( 500 ) ,
2023-09-07 04:19:10 +08:00
" startedSharingAt " timestamp with time zone ,
" stoppedSharingAt " timestamp with time zone ,
" updatedAt " timestamp with time zone ,
" playerPlaybackRate " numeric ,
" playerCurrentTime " numeric ,
" playerPlaying " boolean
2023-05-23 20:09:38 +08:00
) ;
2023-09-07 20:16:30 +08:00
create index " externalVideo_meetingId_current " on " externalVideo " ( " meetingId " ) WHERE " stoppedSharingAt " IS NULL ;
2023-05-23 20:09:38 +08:00
2023-09-07 20:16:30 +08:00
CREATE VIEW " v_externalVideo " AS
SELECT * FROM " externalVideo "
2023-09-07 04:19:10 +08:00
WHERE " stoppedSharingAt " IS NULL ;
2023-05-23 20:09:38 +08:00
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
- - - - Screenshare
create table " screenshare " (
" screenshareId " varchar ( 50 ) primary key ,
" meetingId " varchar ( 100 ) REFERENCES " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" voiceConf " varchar ( 50 ) ,
" screenshareConf " varchar ( 50 ) ,
2024-10-02 01:39:48 +08:00
" contentType " varchar ( 50 ) , - - camera or screenshare
2023-05-23 20:09:38 +08:00
" stream " varchar ( 100 ) ,
" vidWidth " integer ,
" vidHeight " integer ,
2023-05-30 21:01:32 +08:00
" hasAudio " boolean ,
2023-08-08 21:41:16 +08:00
" startedAt " timestamp with time zone ,
2023-08-08 21:51:37 +08:00
" stoppedAt " timestamp with time zone
2023-05-30 21:01:32 +08:00
2023-05-23 20:09:38 +08:00
) ;
create index " screenshare_meetingId " on " screenshare " ( " meetingId " ) ;
create index " screenshare_meetingId_current " on " screenshare " ( " meetingId " ) WHERE " stoppedAt " IS NULL ;
CREATE VIEW " v_screenshare " AS
SELECT * FROM " screenshare "
WHERE " stoppedAt " IS NULL ;
2023-06-13 22:44:51 +08:00
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
- - - - Timer
CREATE TABLE " timer " (
" meetingId " varchar ( 100 ) PRIMARY KEY REFERENCES " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" stopwatch " boolean ,
" running " boolean ,
" active " boolean ,
" time " bigint ,
" accumulated " bigint ,
2024-03-01 01:29:46 +08:00
" startedOn " bigint ,
2023-06-13 22:44:51 +08:00
" songTrack " varchar ( 50 )
) ;
2024-03-05 04:55:42 +08:00
ALTER TABLE " timer " ADD COLUMN " startedAt " timestamp with time zone GENERATED ALWAYS AS ( CASE WHEN " startedOn " = 0 THEN NULL ELSE to_timestamp ( " startedOn " : : double precision / 1000 ) END ) STORED ;
2024-03-01 01:29:46 +08:00
CREATE OR REPLACE VIEW " v_timer " AS
SELECT
" meetingId " ,
" stopwatch " ,
case
when " stopwatch " is true or " running " is false then " running "
2024-05-21 04:12:29 +08:00
when " startedAt " + ( ( " time " - coalesce ( " accumulated " , 0 ) ) * interval ' 1 milliseconds ' ) > = current_timestamp then true
else false
2024-03-01 01:29:46 +08:00
end " running " ,
2024-09-26 03:42:16 +08:00
case when
" stopwatch " is false
and " startedAt " + ( ( " time " - coalesce ( " accumulated " , 0 ) ) * interval ' 1 milliseconds ' ) < = current_timestamp
then true
else false
end " elapsed " ,
2024-03-01 01:29:46 +08:00
" active " ,
" time " ,
" accumulated " ,
" startedAt " ,
" startedOn " ,
" songTrack "
FROM " timer " ;
2023-06-21 23:32:53 +08:00
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
- - - - breakoutRoom
2023-06-23 22:23:41 +08:00
2023-06-30 03:52:59 +08:00
CREATE TABLE " breakoutRoom " (
2023-06-21 23:32:53 +08:00
" breakoutRoomId " varchar ( 100 ) NOT NULL PRIMARY KEY ,
2023-06-30 03:52:59 +08:00
" parentMeetingId " varchar ( 100 ) REFERENCES " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" externalId " varchar ( 100 ) ,
" sequence " numeric ,
" name " varchar ( 100 ) ,
" shortName " varchar ( 100 ) ,
" isDefaultName " bool ,
" freeJoin " bool ,
2023-08-08 21:41:16 +08:00
" startedAt " timestamp with time zone ,
" endedAt " timestamp with time zone ,
2023-06-30 03:52:59 +08:00
" durationInSeconds " int4 ,
" sendInvitationToModerators " bool ,
" captureNotes " bool ,
" captureSlides " bool
2023-06-21 23:32:53 +08:00
) ;
2023-06-23 22:23:41 +08:00
CREATE INDEX " idx_breakoutRoom_parentMeetingId " ON " breakoutRoom " ( " parentMeetingId " , " externalId " ) ;
2023-06-30 03:52:59 +08:00
CREATE TABLE " breakoutRoom_user " (
2023-06-21 23:32:53 +08:00
" breakoutRoomId " varchar ( 100 ) NOT NULL REFERENCES " breakoutRoom " ( " breakoutRoomId " ) ON DELETE CASCADE ,
2024-04-16 23:35:27 +08:00
" meetingId " varchar ( 100 ) ,
" userId " varchar ( 50 ) ,
2023-09-05 22:31:25 +08:00
" joinURL " text ,
2023-08-08 21:41:16 +08:00
" assignedAt " timestamp with time zone ,
2023-09-05 22:31:25 +08:00
" joinedAt " timestamp with time zone ,
" inviteDismissedAt " timestamp with time zone ,
2024-06-13 03:21:31 +08:00
" userJoinedSomeRoomAt " timestamp with time zone ,
" isLastAssignedRoom " boolean ,
" isLastJoinedRoom " boolean ,
" isUserCurrentlyInRoom " boolean ,
2024-04-16 23:35:27 +08:00
CONSTRAINT " breakoutRoom_user_pkey " PRIMARY KEY ( " breakoutRoomId " , " meetingId " , " userId " ) ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2023-06-21 23:32:53 +08:00
) ;
2024-05-02 22:50:19 +08:00
create index " idx_breakoutRoom_user_meeting_user " on " breakoutRoom_user " ( " meetingId " , " userId " ) ;
create index " idx_breakoutRoom_user_user_meeting " on " breakoutRoom_user " ( " userId " , " meetingId " ) ;
2024-06-13 03:21:31 +08:00
ALTER TABLE " breakoutRoom_user " ADD COLUMN " showInvitation " boolean GENERATED ALWAYS AS (
CASE WHEN
" isLastAssignedRoom " IS true
and " isUserCurrentlyInRoom " is null
AND ( " joinedAt " is null or " assignedAt " > " joinedAt " )
AND ( " userJoinedSomeRoomAt " is null or " assignedAt " > " userJoinedSomeRoomAt " )
AND ( " inviteDismissedAt " is null or " assignedAt " > " inviteDismissedAt " )
THEN true
ELSE false
END ) STORED ;
- - AND ( " isModerator " is false OR " sendInvitationToModerators " )
- - Trigger to populate ` isLastAssignedRoom ` and ` isLastJoinedRoom `
CREATE OR REPLACE FUNCTION " ins_upd_del_breakoutRoom_user_trigger_func " ( ) RETURNS TRIGGER AS $ $
BEGIN
IF TG_OP = ' DELETE ' THEN
-- Determine the latest assigned room and latest joined room for the remaining rows
PERFORM
set_last_room ( OLD . " meetingId " , OLD . " userId " ) ;
ELSE
-- For INSERT or UPDATE
PERFORM
set_last_room ( NEW . " meetingId " , NEW . " userId " ) ;
END IF ;
RETURN NULL ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE OR REPLACE FUNCTION set_last_room ( meetingId varchar ( 100 ) , userId varchar ( 50 ) ) RETURNS VOID AS $ $
DECLARE
" latestAssignedRoomId " varchar ( 100 ) ;
" latestJoinedRoomId " varchar ( 100 ) ;
" latestJoinedAt " timestamp with time zone ;
BEGIN
SELECT " breakoutRoomId "
INTO " latestAssignedRoomId "
FROM " breakoutRoom_user "
WHERE " meetingId " = meetingId
AND " userId " = userId
AND " assignedAt " IS NOT NULL
ORDER BY " assignedAt " DESC NULL S LAST
LIMIT 1 ;
SELECT " breakoutRoomId "
INTO " latestJoinedRoomId "
FROM " breakoutRoom_user "
WHERE " meetingId " = meetingId
AND " userId " = userId
AND " joinedAt " IS NOT NULL
ORDER BY " joinedAt " DESC NULL S LAST
LIMIT 1 ;
UPDATE " breakoutRoom_user " bu
SET " isLastAssignedRoom " = CASE
WHEN " latestAssignedRoomId " IS NOT NULL AND bu . " breakoutRoomId " = " latestAssignedRoomId " THEN TRUE
ELSE FALSE
END ,
" isLastJoinedRoom " = CASE
WHEN " latestJoinedRoomId " IS NOT NULL AND bu . " breakoutRoomId " = " latestJoinedRoomId " THEN TRUE
ELSE FALSE
END
WHERE bu . " meetingId " = meetingId
AND bu . " userId " = userId
AND ( bu . " isLastAssignedRoom " IS DISTINCT FROM ( CASE WHEN " latestAssignedRoomId " IS NOT NULL AND bu . " breakoutRoomId " = " latestAssignedRoomId " THEN TRUE ELSE FALSE END )
OR bu . " isLastJoinedRoom " IS DISTINCT FROM ( CASE WHEN " latestJoinedRoomId " IS NOT NULL AND bu . " breakoutRoomId " = " latestJoinedRoomId " THEN TRUE ELSE FALSE END ) ) ;
- - userJoinedSomeRoomAt
SELECT max ( " joinedAt " )
INTO " latestJoinedAt "
from " breakoutRoom_user " bru
where bru . " meetingId " = meetingId
and bru . " userId " = userId ;
update " breakoutRoom_user " set " userJoinedSomeRoomAt " = " latestJoinedAt "
where " breakoutRoom_user " . " meetingId " = meetingId
and " breakoutRoom_user " . " userId " = userId
and " breakoutRoom_user " . " userJoinedSomeRoomAt " ! = " latestJoinedAt " ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER " ins_upd_del_breakoutRoom_user_trigger "
AFTER INSERT OR UPDATE OR DELETE ON " breakoutRoom_user "
FOR EACH ROW EXECUTE FUNCTION " ins_upd_del_breakoutRoom_user_trigger_func " ( ) ;
CREATE OR REPLACE FUNCTION " update_bkroom_isUserCurrentlyInRoom_trigger_func " ( )
RETURNS TRIGGER AS $ $
BEGIN
2024-08-28 22:08:30 +08:00
IF NEW . " currentlyInMeeting " < > OLD . " currentlyInMeeting " THEN
update " breakoutRoom_user " set " isUserCurrentlyInRoom " = a . " currentlyInMeeting "
2024-06-13 03:21:31 +08:00
from (
select
2024-08-28 22:08:30 +08:00
bru . " breakoutRoomId " , bru . " userId " , bkroom_user . " currentlyInMeeting "
2024-06-13 03:21:31 +08:00
from " user " bkroom_user
join meeting_breakout mb on mb . " meetingId " = bkroom_user . " meetingId "
join " breakoutRoom " br on br . " parentMeetingId " = mb . " parentId " and mb . " sequence " = br . " sequence "
join " user " u on u . " meetingId " = br . " parentMeetingId " and bkroom_user . " extId " = u . " extId " | | ' - ' | | br . " sequence "
join " breakoutRoom_user " bru on bru . " userId " = u . " userId " and bru . " breakoutRoomId " = br . " breakoutRoomId "
where bkroom_user . " userId " = NEW . " userId "
) a
where " breakoutRoom_user " . " breakoutRoomId " = a . " breakoutRoomId "
and " breakoutRoom_user " . " userId " = a . " userId " ;
END IF ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
2024-08-28 22:08:30 +08:00
CREATE TRIGGER " update_bkroom_isUserCurrentlyInRoom_trigger " AFTER UPDATE OF " currentlyInMeeting " ON " user "
2024-06-13 03:21:31 +08:00
FOR EACH ROW EXECUTE FUNCTION " update_bkroom_isUserCurrentlyInRoom_trigger_func " ( ) ;
2023-06-21 23:32:53 +08:00
2023-06-23 22:23:41 +08:00
CREATE OR REPLACE VIEW " v_breakoutRoom " AS
2024-06-13 03:21:31 +08:00
SELECT u . " meetingId " as " userMeetingId " , u . " userId " , b . " parentMeetingId " , b . " breakoutRoomId " , b . " freeJoin " ,
b . " sequence " , b . " name " , b . " isDefaultName " ,
2023-09-05 22:31:25 +08:00
b . " shortName " , b . " startedAt " , b . " endedAt " , b . " durationInSeconds " , b . " sendInvitationToModerators " ,
2024-06-13 03:21:31 +08:00
bu . " assignedAt " , bu . " joinURL " , bu . " inviteDismissedAt " , u . " role " = ' MODERATOR ' as " isModerator " ,
bu . " isLastAssignedRoom " , bu . " isLastJoinedRoom " , bu . " isUserCurrentlyInRoom " , bu . " showInvitation " ,
bu . " joinedAt " is not null as " hasJoined "
2023-09-05 22:31:25 +08:00
FROM " user " u
JOIN " breakoutRoom " b ON b . " parentMeetingId " = u . " meetingId "
2024-04-16 23:35:27 +08:00
LEFT JOIN " breakoutRoom_user " bu ON bu . " meetingId " = u . " meetingId " AND bu . " userId " = u . " userId " AND bu . " breakoutRoomId " = b . " breakoutRoomId "
2023-09-05 22:31:25 +08:00
WHERE ( bu . " assignedAt " IS NOT NULL
OR b . " freeJoin " IS TRUE
OR u . " role " = ' MODERATOR ' )
2024-06-13 03:21:31 +08:00
AND b . " endedAt " IS NULL ;
2023-06-23 22:23:41 +08:00
CREATE OR REPLACE VIEW " v_breakoutRoom_assignedUser " AS
2024-04-18 02:55:59 +08:00
SELECT " parentMeetingId " , " breakoutRoomId " , " userMeetingId " , " userId "
2023-06-21 23:32:53 +08:00
FROM " v_breakoutRoom "
2023-06-23 22:23:41 +08:00
WHERE " assignedAt " IS NOT NULL ;
2023-06-21 23:32:53 +08:00
2023-09-05 22:31:25 +08:00
- - TODO improve performance ( and handle two users with same extId )
2024-04-18 02:55:59 +08:00
CREATE OR REPLACE VIEW " v_breakoutRoom_participant " as
2024-04-18 19:29:25 +08:00
SELECT DISTINCT
" parentMeetingId " ,
" breakoutRoomId " ,
" userMeetingId " ,
" userId " ,
false as " isAudioOnly "
2023-09-05 22:31:25 +08:00
FROM " v_breakoutRoom "
2024-06-13 03:21:31 +08:00
WHERE " isUserCurrentlyInRoom " IS TRUE
2024-04-18 19:29:25 +08:00
union - - include users that joined only with audio
2024-04-18 02:55:59 +08:00
select parent_user . " meetingId " as " parentMeetingId " ,
bk_user . " meetingId " as " breakoutRoomId " ,
2024-04-18 19:29:25 +08:00
parent_user . " meetingId " as " userMeetingId " ,
parent_user . " userId " ,
true as " isAudioOnly "
2024-04-18 02:55:59 +08:00
from " user " bk_user
join " user " parent_user on parent_user . " userId " = bk_user . " userId " and parent_user . " transferredFromParentMeeting " is false
where bk_user . " transferredFromParentMeeting " is true
and bk_user . " loggedOut " is false ;
2024-04-16 23:35:27 +08:00
- - SELECT DISTINCT br . " parentMeetingId " , br . " breakoutRoomId " , " user " . " meetingId " , " user " . " userId "
2023-09-05 22:31:25 +08:00
- - FROM v_user " user "
- - JOIN " meeting " m using ( " meetingId " )
- - JOIN " v_meeting_breakoutPolicies " vmbp using ( " meetingId " )
- - JOIN " breakoutRoom " br ON br . " parentMeetingId " = vmbp . " parentId " AND br . " externalId " = m . " extId " ;
- - User to update " inviteDismissedAt " via Mutation
2023-12-08 21:49:57 +08:00
CREATE OR REPLACE VIEW " v_breakoutRoom_user " AS
SELECT bu . *
FROM " breakoutRoom_user " bu
where bu . " breakoutRoomId " in (
select b . " breakoutRoomId "
from " user " u
join " breakoutRoom " b on b . " parentMeetingId " = u . " meetingId " and b . " endedAt " is null
2024-04-16 23:35:27 +08:00
where u . " meetingId " = bu . " meetingId "
and u . " userId " = bu . " userId "
2023-12-08 21:49:57 +08:00
) ;
2023-06-21 23:32:53 +08:00
2023-08-25 22:42:26 +08:00
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
- - - - sharedNotes
create table " sharedNotes " (
" meetingId " varchar ( 100 ) references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" sharedNotesExtId " varchar ( 25 ) ,
" padId " varchar ( 25 ) ,
" model " varchar ( 25 ) ,
" name " varchar ( 25 ) ,
" pinned " boolean ,
constraint " pk_sharedNotes " primary key ( " meetingId " , " sharedNotesExtId " )
) ;
2024-05-02 22:50:19 +08:00
create index " idx_sharedNotes_pk_reverse " on " sharedNotes " ( " sharedNotesExtId " , " meetingId " ) ;
2023-08-25 22:42:26 +08:00
create table " sharedNotes_rev " (
" meetingId " varchar ( 100 ) references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" sharedNotesExtId " varchar ( 25 ) ,
" rev " integer ,
2024-04-16 23:35:27 +08:00
" userId " varchar ( 50 ) ,
2023-10-24 04:26:29 +08:00
" changeset " text ,
2023-08-25 22:42:26 +08:00
" start " integer ,
" end " integer ,
" diff " TEXT ,
" createdAt " timestamp with time zone ,
2024-04-16 23:35:27 +08:00
constraint " pk_sharedNotes_rev " primary key ( " meetingId " , " sharedNotesExtId " , " rev " ) ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE SET NULL
2023-08-25 22:42:26 +08:00
) ;
2024-05-02 22:50:19 +08:00
create index " idx_sharedNotes_rev_pk_reverse " on " sharedNotes_rev " ( " sharedNotesExtId " , " meetingId " ) ;
create index " idx_sharedNotes_rev_user_meeting " on " sharedNotes_rev " ( " userId " , " meetingId " ) ;
2023-08-25 22:42:26 +08:00
- - create view " v_sharedNotes_rev " as select * from " sharedNotes_rev " ;
2024-01-19 03:40:09 +08:00
create view " v_sharedNotes_diff " as
2024-01-19 10:31:06 +08:00
select " meetingId " , " sharedNotesExtId " , " userId " , " start " , " end " , " diff " , " rev "
2024-01-19 03:40:09 +08:00
from " sharedNotes_rev "
where " diff " is not null ;
2023-08-25 22:42:26 +08:00
create table " sharedNotes_session " (
" meetingId " varchar ( 100 ) references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" sharedNotesExtId " varchar ( 25 ) ,
2024-04-16 23:35:27 +08:00
" userId " varchar ( 50 ) ,
2023-08-25 22:42:26 +08:00
" sessionId " varchar ( 50 ) ,
2024-04-16 23:35:27 +08:00
constraint " pk_sharedNotes_session " primary key ( " meetingId " , " sharedNotesExtId " , " userId " ) ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2023-08-25 22:42:26 +08:00
) ;
2024-04-16 23:35:27 +08:00
create index " sharedNotes_session_userId " on " sharedNotes_session " ( " meetingId " , " userId " ) ;
2024-05-02 22:50:19 +08:00
create index " sharedNotes_session_userId_rev " on " sharedNotes_session " ( " userId " , " meetingId " ) ;
2023-08-25 22:42:26 +08:00
create view " v_sharedNotes " as
SELECT sn . * , max ( snr . rev ) " lastRev "
FROM " sharedNotes " sn
LEFT JOIN " sharedNotes_rev " snr ON snr . " meetingId " = sn . " meetingId " AND snr . " sharedNotesExtId " = sn . " sharedNotesExtId "
GROUP BY sn . " meetingId " , sn . " sharedNotesExtId " ;
create view " v_sharedNotes_session " as
SELECT sns . * , sn . " padId "
FROM " sharedNotes_session " sns
JOIN " sharedNotes " sn ON sn . " meetingId " = sns . " meetingId " AND sn . " sharedNotesExtId " = sn . " sharedNotesExtId " ;
2023-08-02 09:21:13 +08:00
- - - - - - - - - - - - - - - - - - - - --
CREATE OR REPLACE VIEW " v_current_time " AS
SELECT
2023-08-08 21:41:16 +08:00
current_timestamp AS " currentTimestamp " ,
FLOOR ( EXTRACT ( EPOCH FROM current_timestamp ) * 1000 ) : : bigint AS " currentTimeMillis " ;
2023-08-10 03:44:45 +08:00
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
2024-06-14 02:47:54 +08:00
- - - - caption
2024-04-19 22:42:45 +08:00
CREATE TABLE " caption_locale " (
" meetingId " varchar ( 100 ) NOT NULL REFERENCES " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" locale " varchar ( 15 ) NOT NULL ,
" captionType " varchar ( 100 ) NOT NULL , - - Audio Transcription or Typed Caption
2024-06-04 04:14:32 +08:00
" createdBy " varchar ( 50 ) ,
2024-04-19 22:42:45 +08:00
" createdAt " timestamp with time zone default current_timestamp ,
" updatedAt " timestamp with time zone ,
CONSTRAINT " caption_locale_pk " primary key ( " meetingId " , " locale " , " captionType " ) ,
2024-06-04 04:14:32 +08:00
FOREIGN KEY ( " meetingId " , " createdBy " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2024-04-19 22:42:45 +08:00
) ;
2024-05-02 22:50:19 +08:00
create index " idx_caption_locale_pk_reverse " on " caption_locale " ( " locale " , " meetingId " , " captionType " ) ;
create index " idx_caption_locale_pk_reverse_b " on " caption_locale " ( " captionType " , " meetingId " , " locale " ) ;
2023-08-10 03:44:45 +08:00
2023-10-24 04:26:29 +08:00
CREATE TABLE " caption " (
" captionId " varchar ( 100 ) NOT NULL PRIMARY KEY ,
" meetingId " varchar ( 100 ) NOT NULL REFERENCES " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" captionType " varchar ( 100 ) NOT NULL , - - Audio Transcription or Typed Caption
2024-04-16 23:35:27 +08:00
" userId " varchar ( 50 ) ,
2024-04-19 22:42:45 +08:00
" locale " varchar ( 15 ) ,
2023-10-24 04:26:29 +08:00
" captionText " text ,
2024-04-16 23:35:27 +08:00
" createdAt " timestamp with time zone ,
FOREIGN KEY ( " meetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2023-08-10 03:44:45 +08:00
) ;
2024-05-02 22:50:19 +08:00
create index " idx_caption_pk_reverse " on " caption " ( " userId " , " meetingId " ) ;
2023-08-10 03:44:45 +08:00
2024-04-19 22:42:45 +08:00
CREATE OR REPLACE FUNCTION " update_caption_locale_owner_func " ( ) RETURNS TRIGGER AS $ $
BEGIN
WITH upsert AS (
UPDATE " caption_locale " SET
2024-06-04 04:14:32 +08:00
" createdBy " = NEW . " userId " ,
2024-04-19 22:42:45 +08:00
" updatedAt " = current_timestamp
WHERE " meetingId " = NEW . " meetingId " AND " locale " = NEW . " locale " AND " captionType " = NEW . " captionType "
RETURNING * )
2024-06-04 04:14:32 +08:00
INSERT INTO " caption_locale " ( " meetingId " , " locale " , " captionType " , " createdBy " )
2024-04-19 22:42:45 +08:00
SELECT NEW . " meetingId " , NEW . " locale " , NEW . " captionType " , NEW . " userId "
WHERE NOT EXISTS ( SELECT * FROM upsert ) ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER " insert_caption_trigger " BEFORE INSERT ON " caption " FOR EACH ROW
EXECUTE FUNCTION " update_caption_locale_owner_func " ( ) ;
create index idx_caption on caption ( " meetingId " , " locale " , " createdAt " ) ;
create index idx_caption_captionType on caption ( " meetingId " , " locale " , " captionType " , " createdAt " ) ;
2023-10-24 04:26:29 +08:00
CREATE OR REPLACE VIEW " v_caption " AS
2023-09-26 08:31:15 +08:00
SELECT *
2023-10-24 04:26:29 +08:00
FROM " caption "
2023-09-26 08:31:15 +08:00
WHERE " createdAt " > current_timestamp - INTERVAL ' 5 seconds ' ;
2023-09-14 00:37:04 +08:00
2024-04-22 23:30:35 +08:00
CREATE OR REPLACE VIEW " v_caption_activeLocales " AS
2024-06-04 04:14:32 +08:00
select distinct " meetingId " , " locale " , " createdBy " , " captionType "
2024-04-22 23:30:35 +08:00
from " caption_locale " ;
2024-04-11 23:06:20 +08:00
2024-05-02 22:50:19 +08:00
create index " idx_caption_typed_activeLocales " on " caption " ( " meetingId " , " locale " , " userId " ) where " captionType " = ' TYPED ' ;
2024-04-11 23:06:20 +08:00
2023-09-14 00:37:04 +08:00
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
- - --
CREATE TABLE " layout " (
" meetingId " varchar ( 100 ) primary key references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" currentLayoutType " varchar ( 100 ) ,
" presentationMinimized " boolean ,
" cameraDockIsResizing " boolean ,
" cameraDockPlacement " varchar ( 100 ) ,
" cameraDockAspectRatio " numeric ,
" cameraWithFocus " varchar ( 100 ) ,
" propagateLayout " boolean ,
" updatedAt " timestamp with time zone
) ;
CREATE VIEW " v_layout " AS
SELECT * FROM " layout " ;
2023-10-26 22:53:41 +08:00
2024-04-12 22:31:16 +08:00
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
- - --
CREATE TABLE " notification " (
" notificationId " serial primary key ,
" meetingId " varchar ( 100 ) references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" notificationType " varchar ( 100 ) ,
" icon " varchar ( 100 ) ,
" messageId " varchar ( 100 ) ,
" messageDescription " varchar ( 100 ) ,
" messageValues " jsonb ,
" role " varchar ( 100 ) , - - MODERATOR , PRESENTER , VIEWER
2024-04-19 22:42:45 +08:00
" userMeetingId " varchar ( 100 ) ,
2024-04-16 23:35:27 +08:00
" userId " varchar ( 50 ) ,
" createdAt " timestamp with time zone DEFAULT current_timestamp ,
2024-04-17 21:36:53 +08:00
FOREIGN KEY ( " userMeetingId " , " userId " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2024-04-12 22:31:16 +08:00
) ;
2024-05-02 22:50:19 +08:00
create index " idx_notification_user_meeting " on " notification " ( " userId " , " meetingId " , " createdAt " ) ;
create index " idx_notification_meeting_user " on " notification " ( " meetingId " , " userId " , " createdAt " ) ;
2024-04-12 22:31:16 +08:00
create or replace VIEW " v_notification " AS
select u . " meetingId " ,
u . " userId " ,
n . " notificationId " ,
n . " notificationType " ,
n . " icon " ,
n . " messageId " ,
n . " messageDescription " ,
n . " messageValues " ,
n . " role " ,
case when n . " userId " = u . " userId " then true else false end " isSingleUserNotification " ,
n . " createdAt "
from notification n
join " user " u on n . " meetingId " = u . " meetingId " and ( n . " userId " is null or n . " userId " = u . " userId " )
where (
n . " role " is null or
n . " role " = u . " role " or
( n . " role " = ' PRESENTER ' and u . presenter is true )
)
2024-04-12 22:36:46 +08:00
and n . " createdAt " > u . " registeredAt "
2024-04-12 22:31:16 +08:00
and n . " createdAt " > current_timestamp - ' 5 seconds ' : : interval ;
create index idx_notification on notification ( " meetingId " , " userId " , " role " , " createdAt " ) ;
2024-10-03 05:34:10 +08:00
-- ========== Plugin tables
create table " plugin " (
" meetingId " varchar ( 100 ) ,
" name " varchar ( 100 ) ,
" javascriptEntrypointUrl " varchar ( 500 ) ,
2024-10-11 02:49:16 +08:00
" javascriptEntrypointIntegrity " varchar ( 500 ) ,
2024-10-03 05:34:10 +08:00
CONSTRAINT " plugin_pk " PRIMARY KEY ( " meetingId " , " name " ) ,
FOREIGN KEY ( " meetingId " ) REFERENCES " meeting " ( " meetingId " ) ON DELETE CASCADE
) ;
create view " v_plugin " as select * from " plugin " ;
2023-10-26 22:53:41 +08:00
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
- - - Plugins Data Channel
CREATE EXTENSION IF NOT EXISTS " uuid-ossp " ;
2024-04-24 05:17:32 +08:00
CREATE TABLE " pluginDataChannelEntry " (
2023-10-26 22:53:41 +08:00
" meetingId " varchar ( 100 ) references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" pluginName " varchar ( 255 ) ,
2024-04-24 05:17:32 +08:00
" channelName " varchar ( 255 ) ,
" entryId " varchar ( 50 ) DEFAULT uuid_generate_v4 ( ) ,
" subChannelName " varchar ( 255 ) ,
2023-10-26 22:53:41 +08:00
" payloadJson " jsonb ,
2024-06-19 04:46:17 +08:00
" createdBy " varchar ( 50 ) ,
2023-10-26 22:53:41 +08:00
" toRoles " varchar [ ] , - - MODERATOR , VIEWER , PRESENTER
" toUserIds " varchar [ ] ,
2024-01-19 10:31:06 +08:00
" createdAt " timestamp with time zone DEFAULT current_timestamp ,
" deletedAt " timestamp with time zone ,
2024-04-24 05:17:32 +08:00
CONSTRAINT " pluginDataChannel_pkey " PRIMARY KEY ( " meetingId " , " pluginName " , " channelName " , " entryId " , " subChannelName " ) ,
2024-06-19 04:46:17 +08:00
FOREIGN KEY ( " meetingId " , " createdBy " ) REFERENCES " user " ( " meetingId " , " userId " ) ON DELETE CASCADE
2023-10-26 22:53:41 +08:00
) ;
2024-05-02 22:50:19 +08:00
create index " idx_pluginDataChannelEntry_pk_reverse " on " pluginDataChannelEntry " ( " pluginName " , " meetingId " , " channelName " , " subChannelName " ) ;
create index " idx_pluginDataChannelEntry_pk_reverse_b " on " pluginDataChannelEntry " ( " channelName " , " pluginName " , " meetingId " , " subChannelName " ) ;
create index " idx_pluginDataChannelEntry_pk_reverse_c " on " pluginDataChannelEntry " ( " subChannelName " , " channelName " , " pluginName " , " meetingId " ) ;
2024-04-24 05:17:32 +08:00
create index " idx_pluginDataChannelEntry_channelName " on " pluginDataChannelEntry " ( " meetingId " , " pluginName " , " channelName " , " toRoles " , " toUserIds " , " subChannelName " , " createdAt " ) where " deletedAt " is null ;
create index " idx_pluginDataChannelEntry_roles " on " pluginDataChannelEntry " ( " meetingId " , " toRoles " , " toUserIds " , " createdAt " ) where " deletedAt " is null ;
2023-10-26 22:53:41 +08:00
2024-04-24 05:17:32 +08:00
CREATE OR REPLACE VIEW " v_pluginDataChannelEntry " AS
2024-06-19 04:46:17 +08:00
SELECT u . " meetingId " , u . " userId " , m . " pluginName " , m . " channelName " , m . " subChannelName " , m . " entryId " , m . " payloadJson " , m . " createdBy " , m . " toRoles " , m . " createdAt "
2023-10-26 22:53:41 +08:00
FROM " user " u
2024-04-24 05:17:32 +08:00
JOIN " pluginDataChannelEntry " m ON m . " meetingId " = u . " meetingId "
2023-10-26 22:53:41 +08:00
AND ( ( m . " toRoles " IS NULL AND m . " toUserIds " IS NULL )
OR u . " userId " = ANY ( m . " toUserIds " )
OR u . " role " = ANY ( m . " toRoles " )
OR ( u . " presenter " AND ' PRESENTER ' = ANY ( m . " toRoles " ) )
)
2024-01-19 10:31:06 +08:00
WHERE " deletedAt " is null
2023-10-26 22:53:41 +08:00
ORDER BY m . " createdAt " ;
2023-12-09 02:48:41 +08:00
- - - - - - - - - - - - - - - - - - - - - - --
create view " v_meeting_componentsFlags " as
select " meeting " . " meetingId " ,
2024-04-10 02:41:54 +08:00
( case
when NULL IF ( " durationInSeconds " , 0 ) is null then false
when current_timestamp + ' 30 minutes ' : : interval > ( " createdAt " + ( " durationInSeconds " * ' 1 second ' : : interval ) ) then true
else false
end ) " showRemainingTime " ,
2023-12-09 02:48:41 +08:00
exists (
select 1
from " breakoutRoom "
where " breakoutRoom " . " parentMeetingId " = " meeting " . " meetingId "
and " endedAt " is null
) as " hasBreakoutRoom " ,
exists (
select 1
from " poll "
where " poll " . " meetingId " = " meeting " . " meetingId "
and " ended " is false
and " published " is false
) as " hasPoll " ,
exists (
select 1
from " timer "
where " timer " . " meetingId " = " meeting " . " meetingId "
and " active " is true
) as " hasTimer " ,
exists (
select 1
from " v_screenshare "
where " v_screenshare " . " meetingId " = " meeting " . " meetingId "
2024-06-13 05:42:03 +08:00
and " contentType " = ' screenshare '
2023-12-09 02:48:41 +08:00
) as " hasScreenshare " ,
2024-06-13 05:42:03 +08:00
exists (
select 1
from " v_screenshare "
where " v_screenshare " . " meetingId " = " meeting " . " meetingId "
and " contentType " = ' camera '
) as " hasCameraAsContent " ,
2023-12-09 02:48:41 +08:00
exists (
select 1
from " v_externalVideo "
where " v_externalVideo " . " meetingId " = " meeting " . " meetingId "
) as " hasExternalVideo " ,
2023-12-14 21:54:52 +08:00
exists (
2024-06-04 04:14:32 +08:00
select 1
from " v_caption_activeLocales "
where " v_caption_activeLocales " . " meetingId " = " meeting " . " meetingId "
2024-06-15 03:24:12 +08:00
) as " hasCaption "
2023-12-09 02:48:41 +08:00
from " meeting " ;