2023-04-06 00:56:22 +08:00
DROP VIEW IF EXISTS " v_pres_annotation_curr " ;
DROP VIEW IF EXISTS " v_pres_annotation_history_curr " ;
DROP VIEW IF EXISTS " v_pres_page_cursor " ;
DROP VIEW IF EXISTS " v_pres_page_writers " ;
DROP TABLE IF EXISTS " pres_annotation_history " ;
DROP TABLE IF EXISTS " pres_annotation " ;
DROP TABLE IF EXISTS " pres_page_cursor " ;
DROP TABLE IF EXISTS " pres_page_writers " ;
DROP TABLE IF EXISTS " pres_page " ;
DROP TABLE IF EXISTS " pres_presentation " ;
2023-03-25 00:33:08 +08:00
2023-06-21 23:32:53 +08:00
DROP VIEW IF EXISTS " v_breakoutRoom_participant " ;
DROP VIEW IF EXISTS " v_breakoutRoom_assignedUser " ;
DROP VIEW IF EXISTS " v_breakoutRoom " ;
DROP TABLE IF EXISTS " breakoutRoom_user " ;
DROP TABLE IF EXISTS " breakoutRoom " ;
2023-04-01 04:46:17 +08:00
DROP VIEW IF EXISTS " v_chat " ;
DROP VIEW IF EXISTS " v_chat_message_public " ;
DROP VIEW IF EXISTS " v_chat_message_private " ;
DROP VIEW IF EXISTS " v_chat_participant " ;
2023-04-12 22:30:12 +08:00
DROP VIEW IF EXISTS " v_user_typing_public " ;
2023-04-26 04:12:15 +08:00
DROP VIEW IF EXISTS " v_user_typing_private " ;
2023-04-01 04:46:17 +08:00
DROP TABLE IF EXISTS " chat_user " ;
DROP TABLE IF EXISTS " chat_message " ;
DROP TABLE IF EXISTS " chat " ;
2023-06-21 23:32:53 +08:00
DROP VIEW IF EXISTS " v_poll_response " ;
DROP VIEW IF EXISTS " v_poll_user " ;
DROP VIEW IF EXISTS " v_poll_option " ;
DROP VIEW IF EXISTS " v_poll " ;
DROP TABLE IF EXISTS " poll_response " ;
DROP TABLE IF EXISTS " poll_option " ;
DROP TABLE IF EXISTS " poll " ;
DROP VIEW IF EXISTS " v_external_video " ;
DROP TABLE IF EXISTS " external_video " ;
DROP VIEW IF EXISTS " v_timer " ;
DROP TABLE IF EXISTS " timer " ;
DROP VIEW IF EXISTS " v_screenshare " ;
DROP TABLE IF EXISTS " screenshare " ;
2023-05-24 21:56:22 +08:00
2023-04-01 04:46:17 +08:00
DROP VIEW IF EXISTS " v_user_camera " ;
DROP VIEW IF EXISTS " v_user_voice " ;
- - DROP VIEW IF EXISTS " v_user_whiteboard " ;
DROP VIEW IF EXISTS " v_user_breakoutRoom " ;
2023-04-12 22:07:54 +08:00
DROP VIEW IF EXISTS " v_user " ;
2023-04-17 23:04:38 +08:00
DROP VIEW IF EXISTS " v_user_current " ;
2023-04-12 22:07:54 +08:00
DROP VIEW IF EXISTS " v_user_ref " ;
2023-05-16 04:21:36 +08:00
DROP VIEW IF EXISTS " v_user_customParameter " ;
2023-05-20 02:28:20 +08:00
DROP VIEW IF EXISTS " v_user_welcomeMsgs " ;
2023-04-01 04:46:17 +08:00
DROP TABLE IF EXISTS " user_camera " ;
DROP TABLE IF EXISTS " user_voice " ;
- - DROP TABLE IF EXISTS " user_whiteboard " ;
DROP TABLE IF EXISTS " user_breakoutRoom " ;
2023-04-12 22:30:12 +08:00
DROP TABLE IF EXISTS " user_connectionStatus " ;
2023-05-16 04:21:36 +08:00
DROP TABLE IF EXISTS " user_customParameter " ;
2023-05-30 00:49:36 +08:00
DROP TABLE IF EXISTS " user_localSettings " ;
2023-04-01 04:46:17 +08:00
DROP TABLE IF EXISTS " user " ;
2023-04-20 20:49:16 +08:00
DROP VIEW IF EXISTS " v_meeting_lockSettings " ;
DROP VIEW IF EXISTS " v_meeting_showUserlist " ;
DROP VIEW IF EXISTS " v_meeting_usersPolicies " ;
2023-05-20 00:47:00 +08:00
DROP VIEW IF EXISTS " v_meeting_breakoutPolicies " ;
DROP VIEW IF EXISTS " v_meeting_recordingPolicies " ;
DROP VIEW IF EXISTS " v_meeting_voiceSettings " ;
DROP VIEW IF EXISTS " v_meeting_group " ;
2023-04-20 20:49:16 +08:00
DROP TABLE IF EXISTS " meeting_breakout " ;
DROP TABLE IF EXISTS " meeting_recording " ;
DROP TABLE IF EXISTS " meeting_welcome " ;
DROP TABLE IF EXISTS " meeting_voice " ;
DROP TABLE IF EXISTS " meeting_users " ;
DROP TABLE IF EXISTS " meeting_metadata " ;
DROP TABLE IF EXISTS " meeting_lockSettings " ;
DROP TABLE IF EXISTS " meeting_usersPolicies " ;
DROP TABLE IF EXISTS " meeting_group " ;
DROP TABLE IF EXISTS " meeting " ;
2023-05-20 00:47:00 +08:00
2023-04-20 20:49:16 +08:00
DROP FUNCTION IF EXISTS " update_user_presenter_trigger_func " ;
DROP FUNCTION IF EXISTS " update_pres_presentation_current_trigger_func " ;
DROP FUNCTION IF EXISTS " update_pres_page_current_trigger_func " ;
DROP FUNCTION IF EXISTS " pres_page_writers_update_delete_trigger_func " ;
DROP FUNCTION IF EXISTS " update_user_hasDrawPermissionOnCurrentPage(varchar, varchar) " ;
2023-04-26 02:41:37 +08:00
DROP FUNCTION IF EXISTS " update_user_emoji_time_trigger_func " ;
2023-05-03 21:10:02 +08:00
DROP FUNCTION IF EXISTS " update_chatUser_clear_typingAt_trigger_func " ;
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 ,
" duration " integer
) ;
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
create table " meeting_recording " (
" 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-03-25 00:33:08 +08:00
" keepEvents " boolean
) ;
2023-04-01 04:46:17 +08:00
create index " idx_meeting_recording_meetingId " on " meeting_recording " ( " meetingId " ) ;
2023-05-20 00:47:00 +08:00
create view " v_meeting_recordingPolicies " as select * from meeting_recording ;
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 ) ,
" 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 " ,
" 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 ,
" hideViewersCursor " boolean
) ;
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-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-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-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-03-08 23:23:45 +08:00
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 ,
" extId " varchar ( 50 ) NULL ,
2023-03-25 00:33:08 +08:00
" meetingId " varchar ( 100 ) NULL references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
2023-03-08 23:23:45 +08:00
" name " varchar ( 255 ) NULL ,
2023-03-17 00:56:32 +08:00
" avatar " varchar ( 500 ) NULL ,
" color " varchar ( 7 ) NULL ,
2023-03-08 23:23:45 +08:00
" emoji " varchar ,
2023-04-20 20:49:16 +08:00
" emojiTime " timestamp ,
2023-03-08 23:23:45 +08:00
" guest " bool NULL ,
2023-03-17 00:56:32 +08:00
" guestStatus " varchar ( 50 ) ,
" mobile " bool NULL ,
" clientType " varchar ( 50 ) ,
2023-03-08 23:23:45 +08:00
-- "excludeFromDashboard" bool NULL,
2023-03-17 00:56:32 +08:00
" role " varchar ( 20 ) NULL ,
2023-03-08 23:23:45 +08:00
" authed " bool NULL ,
" joined " bool NULL ,
2023-04-26 02:41:37 +08:00
" disconnected " bool NULL , -- this is the old leftFlag (that was renamed), set when the user just closed the client
" expired " bool NULL , -- when it is been some time the user is disconnected
2023-03-17 00:56:32 +08:00
-- "ejected" bool null,
-- "ejectReason" varchar(255),
2023-03-08 23:23:45 +08:00
" banned " bool NULL ,
2023-04-26 02:50:23 +08:00
" loggedOut " bool NULL , -- when user clicked Leave meeting button
2023-03-17 00:56:32 +08:00
" registeredOn " bigint NULL ,
" presenter " bool NULL ,
2023-03-08 23:23:45 +08:00
" pinned " bool NULL ,
2023-04-20 20:49:16 +08:00
" locked " bool NULL ,
" hasDrawPermissionOnCurrentPage " bool default FALSE
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 ' ;
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
- - Virtual columns isDialIn , isModerator and isOnline
ALTER TABLE " user " ADD COLUMN " isDialIn " boolean GENERATED ALWAYS AS ( CASE WHEN " clientType " = ' dial-in-user ' THEN true ELSE false END ) STORED ;
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-04-26 02:41:37 +08:00
-- user (on update emoji, set new emojiTime)
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 ;
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 " ,
" user " . " avatar " ,
" user " . " color " ,
" 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 " ,
" user " . " presenter " ,
" user " . " pinned " ,
" user " . " locked " ,
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-04-26 02:41:37 +08:00
CASE WHEN " user " . " joined " IS true AND " user " . " expired " IS false AND " user " . " loggedOut " IS false 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
AND " user " . " joined " IS TRUE ;
CREATE INDEX " idx_v_user_meetingId " ON " user " ( " meetingId " )
where " user " . " loggedOut " IS FALSE
AND " user " . " expired " IS FALSE
and " user " . " joined " IS TRUE ;
CREATE INDEX " idx_v_user_meetingId_orderByColumns " ON " user " ( " meetingId " , " role " , " emojiTime " , " isDialIn " , " hasDrawPermissionOnCurrentPage " , " name " , " userId " )
where " user " . " loggedOut " IS FALSE
AND " user " . " expired " IS FALSE
and " user " . " joined " IS TRUE ;
2023-04-20 20:49:16 +08:00
2023-04-12 22:07:54 +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 " ,
" user " . " avatar " ,
" user " . " color " ,
" user " . " emoji " ,
" user " . " guest " ,
" user " . " guestStatus " ,
" user " . " mobile " ,
" user " . " clientType " ,
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-04-26 02:41:37 +08:00
" user " . " disconnected " ,
" user " . " expired " ,
2023-04-17 23:04:38 +08:00
" user " . " banned " ,
" user " . " loggedOut " ,
" user " . " registeredOn " ,
" user " . " presenter " ,
" user " . " pinned " ,
" user " . " locked " ,
2023-04-20 20:49:16 +08:00
" user " . " hasDrawPermissionOnCurrentPage " ,
2023-04-17 23:04:38 +08:00
CASE WHEN " user " . " role " = ' MODERATOR ' THEN true ELSE false END " isModerator "
FROM " user " ;
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 " ,
" user " . " avatar " ,
" user " . " color " ,
" 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 " ,
" user " . " presenter " ,
" user " . " pinned " ,
" user " . " locked " ,
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-04-26 02:41:37 +08:00
CASE WHEN " user " . " joined " IS true AND " user " . " expired " IS false AND " user " . " loggedOut " IS false 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-04-04 20:02:41 +08:00
" userId " varchar ( 50 ) PRIMARY KEY NOT NULL REFERENCES " user " ( " userId " ) ON DELETE CASCADE ,
" voiceUserId " varchar ( 100 ) ,
2023-03-17 00:56:32 +08:00
" callerName " varchar ( 100 ) ,
" callerNum " varchar ( 100 ) ,
" callingWith " varchar ( 100 ) ,
" joined " boolean NULL ,
" listenOnly " boolean NULL ,
" muted " boolean NULL ,
" spoke " boolean NULL ,
" talking " boolean NULL ,
" floor " boolean NULL ,
2023-03-08 23:23:45 +08:00
" lastFloorTime " varchar ( 25 ) ,
2023-03-17 00:56:32 +08:00
" voiceConf " varchar ( 100 ) ,
2023-03-08 23:23:45 +08:00
" color " varchar ( 7 ) ,
2023-03-17 00:56:32 +08:00
" endTime " bigint NULL ,
" startTime " bigint NULL
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-04-28 02:55:13 +08:00
ALTER TABLE " user_voice " ADD COLUMN " hideTalkingIndicatorAt " timestamp GENERATED ALWAYS AS ( to_timestamp ( ( COALESCE ( " endTime " , " startTime " ) + 6000 ) / 1000 ) ) STORED ;
CREATE INDEX " idx_user_voice_userId_talking " ON " user_voice " ( " userId " , " hideTalkingIndicatorAt " , " startTime " ) ;
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 " ,
case when " hideTalkingIndicatorAt " > current_timestamp then true else false end " showTalkingIndicator "
FROM " user " u
JOIN " user_voice " ON u . " userId " = " user_voice " . " userId " ;
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-04-06 00:56:22 +08:00
" status " varchar ( 15 ) ,
" statusUpdatedAt " timestamp ,
" connectionAliveAt " timestamp
) ;
create index " idx_user_connectionStatus_meetingId " on " user_connectionStatus " ( " meetingId " ) ;
- - 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-05-30 00:48:09 +08:00
CREATE TABLE " user_localSettings " (
" userId " varchar ( 50 ) REFERENCES " user " ( " userId " ) ON DELETE CASCADE ,
" meetingId " varchar ( 100 ) NULL references " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" settingsJson " jsonb
) ;
CREATE INDEX " idx_user_local_settings_meetingId " ON " user_localSettings " ( " meetingId " ) ;
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-03-29 20:55:41 +08:00
" lastSeenAt " bigint ,
2023-04-06 00:56:22 +08:00
" typingAt " timestamp ,
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 ;
CREATE INDEX " idx_chat_user_typing_public " ON " chat_user " ( " meetingId " , " typingAt " )
2023-05-03 20:04:44 +08:00
WHERE " chatId " = ' MAIN-PUBLIC-GROUP-CHAT '
2023-05-03 21:10:02 +08:00
AND " typingAt " is not null ;
2023-05-03 20:04:44 +08:00
2023-05-03 21:10:02 +08:00
CREATE INDEX " idx_chat_user_typing_private " ON " chat_user " ( " meetingId " , " userId " , " chatId " , " typingAt " )
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-05-03 21:10:02 +08:00
CREATE INDEX " idx_chat_with_user_typing_private " ON " chat_user " ( " meetingId " , " userId " , " chatId " , " typingAt " )
WHERE " chatId " ! = ' MAIN-PUBLIC-GROUP-CHAT '
AND " typingAt " 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
SELECT " meetingId " , " chatId " , " userId " , " typingAt " ,
CASE WHEN " typingAt " > current_timestamp - INTERVAL ' 5 seconds ' THEN true ELSE false END AS " isCurrentlyTyping "
FROM chat_user
2023-05-03 20:04:44 +08:00
WHERE " chatId " = ' MAIN-PUBLIC-GROUP-CHAT '
2023-05-03 21:10:02 +08:00
AND " typingAt " 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
SELECT chat_user . " meetingId " , chat_user . " chatId " , chat_user . " userId " as " queryUserId " , chat_with . " userId " , chat_with . " typingAt " ,
CASE WHEN chat_with . " typingAt " > current_timestamp - INTERVAL ' 5 seconds ' THEN true ELSE false END AS " isCurrentlyTyping "
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 "
AND chat_with . " typingAt " 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 ) ,
" createdTime " bigint ,
" 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 ) ,
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-05-03 21:10:02 +08:00
CREATE OR REPLACE FUNCTION " update_chatUser_clear_typingAt_trigger_func " ( ) RETURNS TRIGGER AS $ $
2023-05-03 20:04:44 +08:00
BEGIN
UPDATE " chat_user "
2023-05-03 21:10:02 +08:00
SET " typingAt " = null
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-05-03 21:10:02 +08:00
CREATE TRIGGER " update_chatUser_clear_typingAt_trigger " AFTER INSERT ON chat_message FOR EACH ROW
EXECUTE FUNCTION " update_chatUser_clear_typingAt_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-04-04 04:23:30 +08:00
sum ( CASE WHEN cm . " senderId " ! = " user " . " userId " and cm . " createdTime " > coalesce ( cu . " lastSeenAt " , 0 ) THEN 1 ELSE 0 end ) " totalUnread " ,
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
GROUP BY " user " . " userId " , chat . " meetingId " , chat . " chatId " , cu . " visible " , chat_with . " userId " ;
2023-03-29 20:55:41 +08:00
CREATE OR REPLACE VIEW " v_chat_message_public " AS
2023-04-27 03:19:58 +08:00
SELECT cm . * ,
to_timestamp ( " createdTime " / 1000 ) AS " createdTimeAsDate "
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 " ,
cm . * ,
to_timestamp ( " createdTime " / 1000 ) AS " createdTimeAsDate "
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 ,
" current " boolean ,
" downloadable " boolean ,
" removable " boolean
) ;
CREATE INDEX " idx_pres_presentation_meetingId " ON " pres_presentation " ( " meetingId " ) ;
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 ,
" urls " TEXT ,
" current " boolean ,
" xOffset " NUMERIC ,
" yOffset " NUMERIC ,
" widthRatio " NUMERIC ,
" heightRatio " NUMERIC
) ;
CREATE INDEX " idx_pres_page_presentationId " ON " pres_page " ( " presentationId " ) ;
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-04-01 04:46:17 +08:00
" lastUpdatedAt " timestamp DEFAULT now ( )
) ;
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
-- "lastUpdatedAt" timestamp DEFAULT now()
) ;
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-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 ,
" lastUpdatedAt " timestamp DEFAULT now ( ) ,
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 ,
" publishedAt " timestamp
) ;
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
create table " external_video " (
" externalVideoId " varchar ( 100 ) primary key ,
" meetingId " varchar ( 100 ) REFERENCES " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" externalVideoUrl " varchar ( 500 ) ,
" startedAt " timestamp ,
" stoppedAt " timestamp ,
" lastEventAt " timestamp ,
" lastEventDesc " varchar ( 50 ) ,
" playerRate " numeric ,
" playerTime " numeric ,
" playerState " integer
) ;
create index " external_video_meetingId_current " on " external_video " ( " meetingId " ) WHERE " stoppedAt " IS NULL ;
CREATE VIEW " v_external_video " AS
SELECT * FROM " external_video "
WHERE " stoppedAt " IS NULL ;
- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - --
- - - - 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-05-23 20:09:38 +08:00
" startedAt " timestamp ,
2023-05-30 21:01:32 +08:00
" stoppedAt " timestamp
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-21 23:32:53 +08:00
CREATE TABLE public . " breakoutRoom " (
" breakoutRoomId " varchar ( 100 ) NOT NULL PRIMARY KEY ,
" parentMeetingId " varchar ( 100 ) NULL REFERENCES " meeting " ( " meetingId " ) ON DELETE CASCADE ,
" externalId " varchar ( 100 ) NULL ,
" sequence " numeric NULL ,
" name " varchar ( 100 ) NULL ,
" shortName " varchar ( 100 ) NULL ,
" isDefaultName " bool NULL ,
2023-06-23 22:23:41 +08:00
" freeJoin " bool NULL ,
2023-06-21 23:32:53 +08:00
" startedAt " timestamp NULL ,
" endedAt " timestamp NULL ,
" durationInSeconds " int4 NULL ,
" captureNotes " bool NULL ,
" captureSlides " bool NULL
) ;
2023-06-23 22:23:41 +08:00
CREATE INDEX " idx_breakoutRoom_parentMeetingId " ON " breakoutRoom " ( " parentMeetingId " , " externalId " ) ;
2023-06-21 23:32:53 +08:00
CREATE TABLE public . " breakoutRoom_user " (
" breakoutRoomId " varchar ( 100 ) NOT NULL REFERENCES " breakoutRoom " ( " breakoutRoomId " ) ON DELETE CASCADE ,
" userId " varchar ( 50 ) NOT NULL REFERENCES " user " ( " userId " ) ON DELETE CASCADE ,
2023-06-23 22:23:41 +08:00
" assignedAt " timestamp NULL ,
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
SELECT u . " userId " , b . " parentMeetingId " , b . " breakoutRoomId " , b . " freeJoin " , b . " sequence " , b . " name " , b . " isDefaultName " ,
b . " shortName " , b . " startedAt " , b . " endedAt " , b . " durationInSeconds " ,
2023-06-21 23:32:53 +08:00
CASE WHEN b . " durationInSeconds " = 0 THEN NULL ELSE b . " startedAt " + b . " durationInSeconds " * ' 1 second ' : : INTERVAL END AS " willEndAt " ,
2023-06-23 22:23:41 +08:00
bu . " assignedAt " , ub . " isOnline " AS " currentIsOnline " , ub . " registeredOn " AS " currentRegisteredOn " , ub . " joined " AS " currentJoined "
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 ;
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-06-23 22:23:41 +08:00
CREATE OR REPLACE VIEW " v_breakoutRoom_participant " AS
2023-06-21 23:32:53 +08:00
SELECT DISTINCT br . " parentMeetingId " , br . " breakoutRoomId " , " user " . " userId "
FROM v_user " user "
JOIN " meeting " m using ( " meetingId " )
JOIN " v_meeting_breakoutPolicies " vmbp using ( " meetingId " )
2023-06-23 22:23:41 +08:00
JOIN " breakoutRoom " br ON br . " parentMeetingId " = vmbp . " parentId " AND br . " externalId " = m . " extId " ;
2023-06-21 23:32:53 +08:00