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 ;
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 ) ,
" html5InstanceId " varchar ( 100 ) ,
" createdTime " bigint ,
2023-10-12 20:55:12 +08:00
" durationInSeconds " integer
2023-03-25 00:33:08 +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
2023-08-08 21:41:16 +08:00
create view " v_meeting " as select * from " meeting " ;
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
" welcomeMsgTemplate " text ,
" 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 ,
" maxUsers " integer ,
" maxUserConcurrentAccesses " integer ,
" webcamsOnlyForModerator " boolean ,
" userCameraCap " integer ,
" guestPolicy " varchar ( 100 ) ,
2023-06-29 10:08:03 +08:00
" guestLobbyMessage " text ,
2023-03-25 00:33:08 +08:00
" meetingLayout " varchar ( 100 ) ,
" allowModsToUnmuteUsers " boolean ,
" allowModsToEjectCameras " boolean ,
" authenticatedGuest " boolean
) ;
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 " ,
" 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
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 " ,
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-04-19 04:40:46 +08:00
CREATE OR REPLACE VIEW " v_meeting_showUserlist " AS
SELECT " meetingId "
FROM " meeting_lockSettings "
WHERE " hideUserList " IS FALSE ;
CREATE INDEX " idx_meeting_lockSettings_hideUserList_false " ON " meeting_lockSettings " ( " meetingId " ) WHERE " hideUserList " IS FALSE ;
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 " (
2023-03-17 00:56:32 +08:00
" userId " varchar ( 50 ) NOT NULL PRIMARY KEY ,
2023-06-30 03:52:59 +08:00
" extId " varchar ( 50 ) ,
" meetingId " varchar ( 100 ) references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" name " varchar ( 255 ) ,
" role " varchar ( 20 ) ,
" avatar " varchar ( 500 ) ,
" color " varchar ( 7 ) ,
2023-09-30 07:05:23 +08:00
" sessionToken " varchar ( 16 ) ,
2023-06-30 03:52:59 +08:00
" authed " bool ,
" joined " bool ,
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
" 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 ) ,
2023-06-29 10:08:03 +08:00
- - columns of user state bellow
" 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 ,
2023-03-08 23:23:45 +08:00
" emoji " varchar ,
2023-08-08 21:41:16 +08:00
" emojiTime " timestamp with time zone ,
2023-06-30 03:52:59 +08:00
" guestStatusSetByModerator " varchar ( 50 ) references " user " ( " userId " ) ON DELETE SET NULL ,
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 ) ,
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 ) ,
2023-06-30 03:52:59 +08:00
" ejectedByModerator " varchar ( 50 ) references " user " ( " userId " ) ON DELETE SET NULL ,
" presenter " bool ,
" pinned " bool ,
" locked " bool ,
2023-07-05 21:05:25 +08:00
" speechLocale " varchar ( 255 ) ,
2023-07-20 06:13:21 +08:00
" hasDrawPermissionOnCurrentPage " bool default FALSE ,
2023-08-08 21:41:16 +08:00
" echoTestRunningAt " timestamp with time zone
2023-03-08 23:23:45 +08:00
) ;
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
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
2023-09-05 22:31:25 +08:00
2023-06-29 10:30:02 +08:00
- - Virtual columns isDialIn , isModerator , isOnline , isWaiting , isAllowed , isDenied
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 ;
2023-09-05 22:31:25 +08:00
2023-09-14 20:49:38 +08:00
- - Used to sort the Userlist
2023-09-14 20:31:49 +08:00
ALTER TABLE " user " ADD COLUMN " nameSortable " varchar ( 255 ) GENERATED ALWAYS AS ( immutable_lower_unaccent ( " name " ) ) STORED ;
2023-06-29 10:30:02 +08:00
CREATE INDEX " idx_user_waiting " ON " user " ( " meetingId " ) where " isWaiting " is true ;
2023-04-12 22:07:54 +08:00
- - ALTER TABLE " user " ADD COLUMN " isModerator " boolean GENERATED ALWAYS AS ( CASE WHEN " role " = ' MODERATOR ' THEN true ELSE false END ) STORED ;
- - ALTER TABLE " user " ADD COLUMN " isOnline " boolean GENERATED ALWAYS AS ( CASE WHEN " joined " IS true AND " loggedOut " IS false THEN true ELSE false END ) STORED ;
2023-06-29 10:08:03 +08:00
-- user (on update emoji, raiseHand or away: set new time)
2023-04-26 02:41:37 +08:00
CREATE OR REPLACE FUNCTION update_user_emoji_time_trigger_func ( )
RETURNS TRIGGER AS $ $
BEGIN
IF NEW . " emoji " < > OLD . " emoji " THEN
IF NEW . " emoji " = ' none ' or NEW . " emoji " = ' ' THEN
NEW . " emojiTime " : = NULL ;
ELSE
NEW . " emojiTime " : = NOW ( ) ;
END IF ;
END IF ;
2023-06-29 10:08:03 +08:00
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 ;
2023-04-26 02:41:37 +08:00
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER update_user_emoji_time_trigger BEFORE UPDATE OF " emoji " ON " user "
FOR EACH ROW EXECUTE FUNCTION update_user_emoji_time_trigger_func ( ) ;
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 " ,
2023-04-12 22:07:54 +08:00
" user " . " emoji " ,
2023-04-20 20:49:16 +08:00
" user " . " emojiTime " ,
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 " ,
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 " ,
2023-09-26 22:32:05 +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 " isOnline "
2023-04-12 22:07:54 +08:00
FROM " user "
WHERE " user " . " loggedOut " IS FALSE
2023-04-26 02:41:37 +08:00
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 ;
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 ;
2023-09-14 20:31:49 +08:00
CREATE INDEX " idx_v_user_meetingId_orderByColumns " ON " user " ( " meetingId " , " role " , " raiseHandTime " , " awayTime " , " emojiTime " , " isDialIn " , " hasDrawPermissionOnCurrentPage " , " nameSortable " , " userId " )
2023-04-26 02:41:37 +08:00
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 ;
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 " ,
" user " . " meetingId " ,
" user " . " name " ,
2023-09-14 20:31:49 +08:00
" user " . " nameSortable " ,
2023-04-17 23:04:38 +08:00
" user " . " avatar " ,
" user " . " color " ,
2023-06-29 10:08:03 +08:00
" user " . " away " ,
" user " . " raiseHand " ,
2023-04-17 23:04:38 +08:00
" user " . " emoji " ,
" user " . " guest " ,
2023-06-29 10:08:03 +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 " ,
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 " ,
2023-04-17 23:04:38 +08:00
CASE WHEN " user " . " role " = ' MODERATOR ' THEN true ELSE false END " isModerator "
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-06-29 10:08:03 +08:00
COALESCE ( u . " guestLobbyMessage " , mup . " guestLobbyMessage " ) AS " guestLobbyMessage "
FROM " user " u
2023-12-07 02:17:30 +08:00
JOIN " meeting_usersPolicies " mup using ( " meetingId " )
where u . " guestStatus " ! = ' ALLOW ' ;
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 "
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 " . " raiseHand " ,
2023-04-12 22:07:54 +08:00
" user " . " emoji " ,
" 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 " ,
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 " ,
2023-09-26 22:32:05 +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 " isOnline "
2023-04-12 22:07:54 +08:00
FROM " user " ;
2023-04-06 00:56:22 +08:00
2023-05-20 00:47:00 +08:00
create table " user_customParameter " (
" userId " varchar ( 50 ) REFERENCES " user " ( " userId " ) ON DELETE CASCADE ,
" parameter " varchar ( 255 ) ,
" value " varchar ( 255 ) ,
CONSTRAINT " user_customParameter_pkey " PRIMARY KEY ( " userId " , " parameter " )
) ;
CREATE VIEW " v_user_customParameter " AS
SELECT u . " meetingId " , " user_customParameter " . *
FROM " user_customParameter "
JOIN " user " u ON u . " userId " = " user_customParameter " . " userId " ;
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 " ) ;
2023-03-25 00:33:08 +08:00
CREATE TABLE " user_voice " (
2023-11-16 21:59:08 +08:00
" userId " varchar ( 50 ) PRIMARY KEY NOT NULL REFERENCES " user " ( " userId " ) ON DELETE CASCADE ,
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 ,
" startTime " bigint
2023-03-08 23:23:45 +08:00
) ;
2023-04-04 20:02:41 +08:00
- - CREATE INDEX " idx_user_voice_userId " ON " user_voice " ( " userId " ) ;
2023-08-23 00:45:33 +08:00
ALTER TABLE " user_voice " ADD COLUMN " hideTalkingIndicatorAt " timestamp with time zone
2023-12-07 22:20:46 +08:00
GENERATED ALWAYS AS ( to_timestamp ( ( COALESCE ( " endTime " , " startTime " ) + 6000 ) / 1000 ) ) STORED ;
2023-08-23 00:45:33 +08:00
CREATE INDEX " idx_user_voice_userId_talking " ON " user_voice " ( " userId " , " talking " ) ;
CREATE INDEX " idx_user_voice_userId_hideTalkingIndicatorAt " ON " user_voice " ( " userId " , " hideTalkingIndicatorAt " ) ;
2023-03-17 00:56:32 +08:00
2023-03-25 00:33:08 +08:00
CREATE OR REPLACE VIEW " v_user_voice " AS
2023-03-17 00:56:32 +08:00
SELECT
u . " meetingId " ,
2023-04-04 04:23:30 +08:00
" user_voice " . * ,
2023-04-28 02:55:13 +08:00
greatest ( coalesce ( user_voice . " startTime " , 0 ) , coalesce ( user_voice . " endTime " , 0 ) ) AS " lastSpeakChangedAt " ,
2023-08-23 00:45:33 +08:00
user_talking . " userId " IS NOT NULL " showTalkingIndicator "
2023-04-28 02:55:13 +08:00
FROM " user " u
2023-08-23 00:45:33 +08:00
JOIN " user_voice " ON " user_voice " . " userId " = u . " userId "
LEFT JOIN " user_voice " user_talking ON ( user_talking . " userId " = u . " userId " and user_talking . " talking " IS TRUE )
2023-11-16 21:59:08 +08:00
OR ( user_talking . " userId " = u . " userId " and user_talking . " hideTalkingIndicatorAt " > now ( ) )
WHERE " user_voice " . " joined " is true ;
2023-03-17 00:56:32 +08:00
CREATE TABLE " user_camera " (
" streamId " varchar ( 100 ) PRIMARY KEY ,
" userId " varchar ( 50 ) NOT NULL REFERENCES " user " ( " userId " ) ON DELETE CASCADE
) ;
2023-04-01 04:46:17 +08:00
CREATE INDEX " idx_user_camera_userId " ON " user_camera " ( " userId " ) ;
2023-03-08 23:23:45 +08:00
2023-03-17 00:56:32 +08:00
CREATE OR REPLACE VIEW " v_user_camera " AS
SELECT
u . " meetingId " ,
" user_camera " . *
FROM " user_camera "
JOIN " user " u ON u . " userId " = user_camera . " userId " ;
2023-03-08 23:23:45 +08:00
2023-03-17 00:56:32 +08:00
CREATE TABLE " user_breakoutRoom " (
" userId " varchar ( 50 ) PRIMARY KEY REFERENCES " user " ( " userId " ) ON DELETE CASCADE ,
" breakoutRoomId " varchar ( 100 ) ,
" isDefaultName " boolean ,
" sequence " int ,
" shortName " varchar ( 100 ) ,
2023-04-04 04:23:30 +08:00
" currentlyInRoom " boolean
2023-03-17 00:56:32 +08:00
) ;
2023-04-06 00:56:22 +08:00
- - CREATE INDEX " idx_user_breakoutRoom_userId " ON " user_breakoutRoom " ( " userId " ) ;
2023-03-08 23:23:45 +08:00
2023-03-17 00:56:32 +08:00
CREATE OR REPLACE VIEW " v_user_breakoutRoom " AS
SELECT
u . " meetingId " ,
" user_breakoutRoom " . *
FROM " user_breakoutRoom "
JOIN " user " u ON u . " userId " = " user_breakoutRoom " . " userId " ;
2023-03-29 20:55:41 +08:00
2023-04-06 00:56:22 +08:00
CREATE TABLE " user_connectionStatus " (
" userId " varchar ( 50 ) PRIMARY KEY REFERENCES " user " ( " userId " ) ON DELETE CASCADE ,
2023-04-19 20:54:47 +08:00
" meetingId " varchar ( 100 ) REFERENCES " meeting " ( " meetingId " ) ON DELETE CASCADE ,
2023-08-08 21:41:16 +08:00
" connectionAliveAt " timestamp with time zone ,
" userClientResponseAt " timestamp with time zone ,
2023-07-04 22:38:51 +08:00
" rttInMs " numeric ,
" status " varchar ( 25 ) ,
2023-08-08 21:51:37 +08:00
" statusUpdatedAt " timestamp with time zone
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 " ;
2023-07-04 22:38:51 +08:00
- - CREATE TABLE " user_connectionStatusHistory " (
-- "userId" varchar(50) REFERENCES "user"("userId") ON DELETE CASCADE,
-- "rttInMs" numeric,
-- "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,
-- "higherRttInMs" 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 " (
" userId " varchar ( 50 ) REFERENCES " user " ( " userId " ) ON DELETE CASCADE ,
" status " varchar ( 25 ) ,
" occurrencesCount " integer ,
2023-08-08 21:41:16 +08:00
" firstOccurrenceAt " timestamp with time zone ,
" lastOccurrenceAt " timestamp with time zone ,
2023-07-04 22:38:51 +08:00
" lowestRttInMs " numeric ,
" highestRttInMs " numeric ,
" lastRttInMs " numeric ,
CONSTRAINT " user_connectionStatusMetrics_pkey " PRIMARY KEY ( " userId " , " status " )
) ;
create index " idx_user_connectionStatusMetrics_userId " on " user_connectionStatusMetrics " ( " userId " ) ;
- - This function populate rtt , status and the table user_connectionStatusMetrics
CREATE OR REPLACE FUNCTION " update_user_connectionStatus_trigger_func " ( ) RETURNS TRIGGER AS $ $
DECLARE
" newRttInMs " numeric ;
" newStatus " varchar ( 25 ) ;
BEGIN
IF NEW . " connectionAliveAt " IS NULL OR NEW . " userClientResponseAt " IS NULL THEN
RETURN NEW ;
END IF ;
" newRttInMs " : = ( EXTRACT ( EPOCH FROM ( NEW . " userClientResponseAt " - NEW . " connectionAliveAt " ) ) * 1000 ) ;
" newStatus " : = CASE WHEN COALESCE ( " newRttInMs " , 0 ) > 2000 THEN ' critical '
WHEN COALESCE ( " newRttInMs " , 0 ) > 1000 THEN ' danger '
WHEN COALESCE ( " newRttInMs " , 0 ) > 500 THEN ' warning '
ELSE ' normal ' END ;
- - Update table user_connectionStatusMetrics
WITH upsert AS ( UPDATE " user_connectionStatusMetrics " SET
" occurrencesCount " = " user_connectionStatusMetrics " . " occurrencesCount " + 1 ,
" highestRttInMs " = GREATEST ( " user_connectionStatusMetrics " . " highestRttInMs " , " newRttInMs " ) ,
" lowestRttInMs " = LEAST ( " user_connectionStatusMetrics " . " lowestRttInMs " , " newRttInMs " ) ,
" lastRttInMs " = " newRttInMs " ,
" lastOccurrenceAt " = current_timestamp
WHERE " userId " = NEW . " userId " AND " status " = " newStatus " RETURNING * )
INSERT INTO " user_connectionStatusMetrics " ( " userId " , " status " , " occurrencesCount " , " highestRttInMs " , " lowestRttInMs " , " lastRttInMs " , " firstOccurrenceAt " )
SELECT NEW . " userId " , " newStatus " , 1 , " newRttInMs " , " newRttInMs " , " newRttInMs " , current_timestamp
WHERE NOT EXISTS ( SELECT * FROM upsert ) ;
- - Update rttInMs , status , statusUpdatedAt in user_connectionStatus
UPDATE " user_connectionStatus "
SET " rttInMs " = " newRttInMs " ,
" status " = " newStatus " ,
" statusUpdatedAt " = now ( )
WHERE " userId " = NEW . " userId " ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER " update_user_connectionStatus_trigger " AFTER UPDATE OF " userClientResponseAt " ON " user_connectionStatus "
FOR EACH ROW EXECUTE FUNCTION " update_user_connectionStatus_trigger_func " ( ) ;
- - This function clear userClientResponseAt and rttInMs when connectionAliveAt is updated
CREATE OR REPLACE FUNCTION " update_user_connectionStatus_connectionAliveAt_trigger_func " ( ) RETURNS TRIGGER AS $ $
BEGIN
IF NEW . " connectionAliveAt " < > OLD . " connectionAliveAt " THEN
NEW . " userClientResponseAt " : = NULL ;
NEW . " rttInMs " : = NULL ;
END IF ;
RETURN NEW ;
END ;
$ $ LANGUAGE plpgsql ;
CREATE TRIGGER " update_user_connectionStatus_connectionAliveAt_trigger " BEFORE UPDATE OF " connectionAliveAt " ON " user_connectionStatus "
FOR EACH ROW EXECUTE FUNCTION " update_user_connectionStatus_connectionAliveAt_trigger_func " ( ) ;
CREATE OR REPLACE VIEW " v_user_connectionStatusReport " AS
SELECT u . " meetingId " , u . " userId " ,
max ( cs . " connectionAliveAt " ) AS " connectionAliveAt " ,
max ( cs . " status " ) AS " currentStatus " ,
- - COALESCE ( max ( cs . " rttInMs " ) , ( EXTRACT ( EPOCH FROM ( current_timestamp - max ( cs . " connectionAliveAt " ) ) ) * 1000 ) ) AS " rttInMs " ,
CASE WHEN max ( cs . " connectionAliveAt " ) < current_timestamp - INTERVAL ' 10 seconds ' THEN TRUE ELSE FALSE END AS " clientNotResponding " ,
( array_agg ( csm . " status " ORDER BY csm . " lastOccurrenceAt " DESC ) ) [ 1 ] as " lastUnstableStatus " ,
max ( csm . " lastOccurrenceAt " ) AS " lastUnstableStatusAt "
FROM " user " u
JOIN " user_connectionStatus " cs ON cs . " userId " = u . " userId "
LEFT JOIN " user_connectionStatusMetrics " csm ON csm . " userId " = u . " userId " AND csm . " status " ! = ' normal '
GROUP BY u . " meetingId " , u . " userId " ;
CREATE INDEX " idx_user_connectionStatusMetrics_UnstableReport " ON " user_connectionStatusMetrics " ( " userId " ) WHERE " status " ! = ' normal ' ;
2023-09-30 07:05:23 +08:00
CREATE TABLE " user_graphqlConnection " (
" graphqlConnectionId " serial PRIMARY KEY ,
" sessionToken " varchar ( 16 ) ,
" middlewareConnectionId " varchar ( 12 ) ,
" stablishedAt " timestamp with time zone ,
" closedAt " timestamp with time zone
) ;
CREATE INDEX " idx_user_graphqlConnectionsessionToken " ON " user_graphqlConnection " ( " sessionToken " ) ;
2023-07-04 22:38:51 +08:00
- - ALTER TABLE " user_connectionStatus " ADD COLUMN " rttInMs " NUMERIC GENERATED ALWAYS AS
- - ( 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 " (
" userId " varchar ( 50 ) PRIMARY KEY REFERENCES " user " ( " userId " ) ON DELETE CASCADE ,
2023-06-30 03:52:59 +08:00
" meetingId " varchar ( 100 ) references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
2023-11-02 00:26:38 +08:00
" userClientSettingsJson " jsonb
2023-05-30 00:48:09 +08:00
) ;
2023-11-02 00:26:38 +08:00
CREATE INDEX " idx_user_clientSettings_meetingId " ON " user_clientSettings " ( " meetingId " ) ;
CREATE INDEX " idx_user_clientSettings_userId " ON " user_clientSettings " ( " userId " ) ;
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 " (
" userId " varchar ( 50 ) REFERENCES " user " ( " userId " ) ON DELETE CASCADE ,
" 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 ,
" expiresAt " timestamp with time zone
2023-08-08 19:49:40 +08:00
) ;
2023-08-08 21:41:16 +08:00
- - Set expiresAt on isert or update user_reaction
CREATE OR REPLACE FUNCTION " update_user_reaction_trigger_func " ( ) RETURNS TRIGGER AS $ $
BEGIN
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
CREATE INDEX " idx_user_reaction_userId_createdAt " ON " user_reaction " ( " userId " , " expiresAt " ) ;
CREATE VIEW v_user_reaction AS
SELECT u . " meetingId " , ur . " userId " , ur . " reactionEmoji " , ur . " createdAt " , ur . " expiresAt "
FROM " user " u
JOIN " user_reaction " ur ON u . " userId " = ur . " userId " AND " expiresAt " > current_timestamp ;
CREATE VIEW v_user_reaction_current AS
SELECT u . " meetingId " , ur . " userId " , ( array_agg ( ur . " reactionEmoji " ORDER BY ur . " expiresAt " DESC ) ) [ 1 ] as " reactionEmoji "
FROM " user " u
JOIN " user_reaction " ur ON u . " userId " = ur . " userId " AND " expiresAt " > current_timestamp
GROUP BY u . " meetingId " , ur . " userId " ;
2023-05-24 21:56:22 +08:00
2023-05-16 04:21:36 +08:00
2023-03-29 20:55:41 +08:00
-- ===================== CHAT TABLES
CREATE TABLE " chat " (
" chatId " varchar ( 100 ) ,
" meetingId " varchar ( 100 ) REFERENCES " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" access " varchar ( 20 ) ,
" createdBy " varchar ( 25 ) ,
CONSTRAINT " chat_pkey " PRIMARY KEY ( " 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 ,
2023-03-29 20:55:41 +08:00
CONSTRAINT " chat_user_pkey " PRIMARY KEY ( " chatId " , " meetingId " , " userId " ) ,
CONSTRAINT chat_fk FOREIGN KEY ( " chatId " , " meetingId " ) REFERENCES " chat " ( " chatId " , " meetingId " ) ON DELETE CASCADE
) ;
2023-05-03 21:10:02 +08:00
CREATE INDEX " idx_chat_user_chatId " ON " chat_user " ( " meetingId " , " userId " , " chatId " ) WHERE " visible " is true ;
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 ) ,
" correlationId " varchar ( 100 ) ,
" chatEmphasizedText " boolean ,
2023-05-24 21:56:22 +08:00
" message " text ,
" messageType " varchar ( 50 ) ,
" messageMetadata " text ,
2023-03-29 20:55:41 +08:00
" senderId " varchar ( 100 ) ,
" senderName " varchar ( 255 ) ,
" senderRole " varchar ( 20 ) ,
2023-09-26 21:20:29 +08:00
" createdAt " 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
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
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 "
LEFT 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 "
2023-03-29 23:06:48 +08:00
LEFT JOIN " chat_user " chat_with ON chat_with . " meetingId " = chat . " meetingId " AND chat_with . " chatId " = chat . " chatId " AND chat . " chatId " ! = ' MAIN-PUBLIC-GROUP-CHAT ' AND chat_with . " userId " ! = cu . " userId "
2023-03-29 20:55:41 +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
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
2023-04-27 03:19:58 +08:00
SELECT cu . " userId " ,
2023-09-26 21:20:29 +08:00
cm . *
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 "
WHERE cm . " chatId " ! = ' MAIN-PUBLIC-GROUP-CHAT ' ;
2023-03-29 20:55:41 +08:00
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 ,
2023-10-17 22:03:46 +08:00
" uploadCompleted " 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 " ,
2023-10-17 22:03:46 +08:00
pres_page . " uploadCompleted "
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 " ,
( pres_page . " height " * pres_page . " heightRatio " / 100 * LEAST ( pres_page . " maxImageWidth " / pres_page . " width " , pres_page . " maxImageHeight " / pres_page . " height " ) ) AS " scaledViewBoxHeight "
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 ,
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 " ) ;
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 ,
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 " ) ;
2023-04-06 00:56:22 +08:00
CREATE VIEW " v_pres_annotation_curr " AS
2023-04-01 04:46:17 +08:00
SELECT p . " meetingId " , pp . " presentationId " , pa . *
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
2023-04-01 04:46:17 +08:00
SELECT p . " meetingId " , pp . " presentationId " , pah . *
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 ,
" userId " varchar ( 50 ) REFERENCES " user " ( " userId " ) ON DELETE CASCADE ,
" changedModeOn " bigint ,
CONSTRAINT " pres_page_writers_pkey " PRIMARY KEY ( " pageId " , " userId " )
) ;
create index " idx_pres_page_writers_userID " on " pres_page_writers " ( " userId " ) ;
CREATE OR REPLACE VIEW " v_pres_page_writers " AS
SELECT
u . " meetingId " ,
" 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 " user " u ON u . " userId " = " pres_page_writers " . " userId "
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
WHERE v . " userId " = " user " . " userId "
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
PERFORM " update_user_hasDrawPermissionOnCurrentPage " ( NEW . " userId " , NULL ) ;
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
PERFORM " update_user_hasDrawPermissionOnCurrentPage " ( NEW . " userId " , NULL ) ;
ELSIF TG_OP = ' DELETE ' THEN
PERFORM " update_user_hasDrawPermissionOnCurrentPage " ( OLD . " userId " , NULL ) ;
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 ,
" userId " varchar ( 50 ) REFERENCES " user " ( " userId " ) ON DELETE CASCADE ,
" xPercent " numeric ,
" yPercent " numeric ,
2023-08-08 21:53:04 +08:00
" lastUpdatedAt " timestamp with time zone DEFAULT now ( ) ,
2023-04-04 04:23:30 +08:00
CONSTRAINT " pres_page_cursor_pkey " PRIMARY KEY ( " pageId " , " userId " )
) ;
create index " idx_pres_page_cursor_pageId " on " pres_page_cursor " ( " pageId " ) ;
create index " idx_pres_page_cursor_userID " on " pres_page_cursor " ( " userId " ) ;
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
2023-04-04 04:49:24 +08:00
SELECT pres_presentation . " meetingId " , 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 ,
" meetingId " varchar ( 100 ) REFERENCES " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" ownerId " varchar ( 100 ) REFERENCES " user " ( " userId " ) ,
" questionText " TEXT ,
" type " varchar ( 30 ) ,
" secret " boolean ,
" multipleResponses " boolean ,
" ended " boolean ,
" published " boolean ,
2023-08-08 21:51:37 +08:00
" publishedAt " timestamp with time zone
2023-05-20 00:47:00 +08:00
) ;
CREATE INDEX " idx_poll_meetingId " ON " poll " ( " meetingId " ) ;
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 ,
" userId " varchar ( 100 ) REFERENCES " user " ( " userId " ) ON DELETE CASCADE ,
FOREIGN KEY ( " pollId " , " optionId " ) REFERENCES " poll_option " ( " pollId " , " optionId " ) ON DELETE CASCADE
) ;
CREATE INDEX " idx_poll_response_pollId " ON " poll_response " ( " pollId " ) ;
CREATE INDEX " idx_poll_response_userId " ON " poll_response " ( " userId " ) ;
CREATE INDEX " idx_poll_response_pollId_userId " ON " poll_response " ( " pollId " , " userId " ) ;
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 " ,
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
poll . " meetingId " ,
poll . " pollId " ,
poll . " type " ,
poll . " questionText " ,
poll . " ownerId " AS " pollOwnerId " ,
u . " userId " ,
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 "
GROUP BY poll . " pollId " , u . " userId " , u . name ;
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
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
- - - - 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 ) ,
2023-05-30 21:01:32 +08:00
" contentType " varchar ( 50 ) ,
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 ,
" startedAt " bigint ,
" endedAt " bigint ,
" songTrack " varchar ( 50 )
) ;
CREATE VIEW " v_timer " AS
SELECT * 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 ,
" userId " varchar ( 50 ) NOT NULL REFERENCES " user " ( " userId " ) ON DELETE CASCADE ,
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 ,
2023-06-21 23:32:53 +08:00
CONSTRAINT " breakoutRoom_user_pkey " PRIMARY KEY ( " breakoutRoomId " , " userId " )
) ;
2023-06-23 22:23:41 +08:00
CREATE OR REPLACE VIEW " v_breakoutRoom " AS
2023-09-05 22:31:25 +08:00
SELECT * ,
- - showInvitation flag
case WHEN 1 = 1
- - this is not the last room the user joined
-- AND "lastRoomJoinedId" != "breakoutRoomId" --the next condition turn this one useless
- - user didn ' t joined some room after assigned
AND ( " lastRoomJoinedAt " IS NULL OR " lastRoomJoinedAt " < " assignedAt " )
- - user didn ' t close the invitation already
and ( " inviteDismissedAt " is NULL OR " assignedAt " > " inviteDismissedAt " )
- - user is not online in other room
AND " lastRoomIsOnline " IS FALSE
- - this is this the last assignment ?
AND " currentRoomPriority " = 1
- - user is not moderator or sendInviteToMod flag is true
AND ( " isModerator " is false OR " sendInvitationToModerators " )
THEN TRUE ELSE FALSE END " showInvitation "
from (
SELECT u . " userId " , b . " parentMeetingId " , b . " breakoutRoomId " , b . " freeJoin " , b . " sequence " , b . " name " , b . " isDefaultName " ,
b . " shortName " , b . " startedAt " , b . " endedAt " , b . " durationInSeconds " , b . " sendInvitationToModerators " ,
bu . " assignedAt " , bu . " joinURL " , bu . " inviteDismissedAt " , u . " role " = ' MODERATOR ' as " isModerator " ,
- - CASE WHEN b . " durationInSeconds " = 0 THEN NULL ELSE b . " startedAt " + b . " durationInSeconds " * ' 1 second ' : : INTERVAL END AS " willEndAt " ,
ub . " isOnline " AS " currentRoomIsOnline " ,
ub . " registeredAt " AS " currentRoomRegisteredAt " ,
ub . " joined " AS " currentRoomJoined " ,
rank ( ) OVER ( partition BY u . " userId " order by " assignedAt " desc null s last ) as " currentRoomPriority " ,
max ( bu . " joinedAt " ) OVER ( partition BY u . " userId " ) AS " lastRoomJoinedAt " ,
max ( bu . " breakoutRoomId " ) OVER ( partition BY u . " userId " ORDER BY bu . " joinedAt " ) AS " lastRoomJoinedId " ,
sum ( CASE WHEN ub . " isOnline " THEN 1 ELSE 0 END ) OVER ( partition BY u . " userId " ) > 0 as " lastRoomIsOnline "
FROM " user " u
JOIN " breakoutRoom " b ON b . " parentMeetingId " = u . " meetingId "
LEFT JOIN " breakoutRoom_user " bu ON bu . " userId " = u . " userId " AND bu . " breakoutRoomId " = b . " breakoutRoomId "
LEFT JOIN " meeting " mb ON mb . " extId " = b . " externalId "
LEFT JOIN " v_user " ub ON ub . " meetingId " = mb . " meetingId " and ub . " extId " = u . " extId " | | ' - ' | | b . " sequence "
WHERE ( bu . " assignedAt " IS NOT NULL
OR b . " freeJoin " IS TRUE
OR u . " role " = ' MODERATOR ' )
AND b . " endedAt " IS NULL
) a ;
2023-06-23 22:23:41 +08:00
CREATE OR REPLACE VIEW " v_breakoutRoom_assignedUser " AS
2023-06-21 23:32:53 +08:00
SELECT " parentMeetingId " , " breakoutRoomId " , " userId "
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 )
2023-06-23 22:23:41 +08:00
CREATE OR REPLACE VIEW " v_breakoutRoom_participant " AS
2023-09-05 22:31:25 +08:00
SELECT DISTINCT " parentMeetingId " , " breakoutRoomId " , " userId "
FROM " v_breakoutRoom "
WHERE " currentRoomIsOnline " IS TRUE ;
- - SELECT DISTINCT br . " parentMeetingId " , br . " breakoutRoomId " , " user " . " userId "
- - 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
where u . " userId " = bu . " userId "
) ;
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 " )
) ;
create table " sharedNotes_rev " (
" meetingId " varchar ( 100 ) references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" sharedNotesExtId " varchar ( 25 ) ,
" rev " integer ,
" userId " varchar ( 50 ) references " user " ( " userId " ) ON DELETE SET NULL ,
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 ,
constraint " pk_sharedNotes_rev " primary key ( " meetingId " , " sharedNotesExtId " , " rev " )
) ;
- - create view " v_sharedNotes_rev " as select * from " sharedNotes_rev " ;
create table " sharedNotes_session " (
" meetingId " varchar ( 100 ) references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" sharedNotesExtId " varchar ( 25 ) ,
" userId " varchar ( 50 ) references " user " ( " userId " ) ON DELETE CASCADE ,
" sessionId " varchar ( 50 ) ,
constraint " pk_sharedNotes_session " primary key ( " meetingId " , " sharedNotesExtId " , " userId " )
) ;
create index " sharedNotes_session_userId " on " sharedNotes_session " ( " userId " ) ;
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
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
- - - - audioCaption
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
2023-08-29 03:28:23 +08:00
" userId " varchar ( 50 ) REFERENCES " user " ( " userId " ) ON DELETE CASCADE ,
2023-10-20 00:26:04 +08:00
" lang " varchar ( 15 ) ,
2023-10-24 04:26:29 +08:00
" captionText " text ,
2023-08-29 03:28:23 +08:00
" createdAt " timestamp with time zone
2023-08-10 03:44:45 +08:00
) ;
2023-10-24 04:26:29 +08:00
create index idx_caption on caption ( " meetingId " , " lang " , " createdAt " ) ;
create index idx_caption_captionType on caption ( " meetingId " , " lang " , " captionType " , " createdAt " ) ;
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
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
- - --
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
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
- - - Plugins Data Channel
CREATE EXTENSION IF NOT EXISTS " uuid-ossp " ;
CREATE TABLE " pluginDataChannelMessage " (
" meetingId " varchar ( 100 ) references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" pluginName " varchar ( 255 ) ,
" dataChannel " varchar ( 255 ) ,
" messageId " varchar ( 50 ) DEFAULT uuid_generate_v4 ( ) ,
" payloadJson " jsonb ,
" fromUserId " varchar ( 50 ) REFERENCES " user " ( " userId " ) ON DELETE CASCADE ,
" toRoles " varchar [ ] , - - MODERATOR , VIEWER , PRESENTER
" toUserIds " varchar [ ] ,
" createdAt " timestamp with time ZONE DEFAULT current_timestamp ,
CONSTRAINT " pluginDataChannel_pkey " PRIMARY KEY ( " meetingId " , " pluginName " , " dataChannel " , " messageId " )
) ;
create index " idx_pluginDataChannelMessage_dataChannel " on " pluginDataChannelMessage " ( " meetingId " , " pluginName " , " dataChannel " , " toRoles " , " toUserIds " , " createdAt " ) ;
create index " idx_pluginDataChannelMessage_roles " on " pluginDataChannelMessage " ( " meetingId " , " toRoles " , " toUserIds " , " createdAt " ) ;
CREATE OR REPLACE VIEW " v_pluginDataChannelMessage " AS
SELECT u . " meetingId " , u . " userId " , m . " pluginName " , m . " dataChannel " , m . " messageId " , m . " payloadJson " , m . " fromUserId " , m . " toRoles " , m . " createdAt "
FROM " user " u
JOIN " pluginDataChannelMessage " m ON m . " meetingId " = u . " meetingId "
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 " ) )
)
ORDER BY m . " createdAt " ;
2023-12-09 02:48:41 +08:00
- - - - - - - - - - - - - - - - - - - - - - --
create view " v_meeting_componentsFlags " as
select " meeting " . " meetingId " ,
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 "
) as " hasScreenshare " ,
exists (
select 1
from " v_externalVideo "
where " v_externalVideo " . " meetingId " = " meeting " . " meetingId "
) as " hasExternalVideo " ,
(
select array_agg ( distinct " speechLocale " )
from " user "
where " user " . " meetingId " = " meeting " . " meetingId "
and NULL IF ( " speechLocale " , ' ' ) is not null
) as " audioTranscriptionCaption " ,
(
select array_agg ( distinct " name " )
from " sharedNotes "
where " sharedNotes " . " meetingId " = " meeting " . " meetingId "
and " model " = ' captions '
) as " typedCaption "
from " meeting " ;