Skip to content
4 changes: 2 additions & 2 deletions distribution/src/database/openfire_db2.sql
Original file line number Diff line number Diff line change
Expand Up @@ -205,7 +205,7 @@ CREATE TABLE ofMucRoom (
logEnabled INTEGER NOT NULL,
preserveHistOnDel INTEGER NOT NULL,
retireOnDeletion INTEGER NOT NULL,
subject VARCHAR(100),
subject CLOB,
rolesToBroadcast INTEGER NOT NULL,
useReservedNick INTEGER NOT NULL,
canChangeNick INTEGER NOT NULL,
Expand Down Expand Up @@ -403,4 +403,4 @@ INSERT INTO ofUser (username, plainPassword, name, email, creationDate, modifica
INSERT INTO ofMucService (serviceID, subdomain, isHidden) VALUES (1, 'conference', 0);

-- Do this last, as it is used by a continuous integration check to verify that the entire script was executed successfully.
INSERT INTO ofVersion (name, version) VALUES ('openfire', 37);
INSERT INTO ofVersion (name, version) VALUES ('openfire', 38);
4 changes: 2 additions & 2 deletions distribution/src/database/openfire_hsqldb.sql
Original file line number Diff line number Diff line change
Expand Up @@ -202,7 +202,7 @@ CREATE TABLE ofMucRoom (
logEnabled INTEGER NOT NULL,
retireOnDeletion INTEGER NOT NULL,
preserveHistOnDel INTEGER NOT NULL,
subject VARCHAR(100) NULL,
subject LONGVARCHAR NULL,
rolesToBroadcast INTEGER NOT NULL,
useReservedNick INTEGER NOT NULL,
canChangeNick INTEGER NOT NULL,
Expand Down Expand Up @@ -391,7 +391,7 @@ INSERT INTO ofUser (username, plainPassword, name, email, creationDate, modifica
INSERT INTO ofMucService (serviceID, subdomain, isHidden) VALUES (1, 'conference', 0);

// Do this last, as it is used by a continuous integration check to verify that the entire script was executed successfully.
INSERT INTO ofVersion (name, version) VALUES ('openfire', 37);
INSERT INTO ofVersion (name, version) VALUES ('openfire', 38);

// The value is the size in megabytes that the .log file can reach before an automatic
// checkpoint occurs. A checkpoint rewrites the .script file and clears the .log file
Expand Down
4 changes: 2 additions & 2 deletions distribution/src/database/openfire_mysql.sql
Original file line number Diff line number Diff line change
Expand Up @@ -192,7 +192,7 @@ CREATE TABLE ofMucRoom (
logEnabled TINYINT NOT NULL,
retireOnDeletion TINYINT NOT NULL,
preserveHistOnDel TINYINT NOT NULL,
subject VARCHAR(100) NULL,
subject TEXT NULL,
rolesToBroadcast TINYINT NOT NULL,
useReservedNick TINYINT NOT NULL,
canChangeNick TINYINT NOT NULL,
Expand Down Expand Up @@ -381,4 +381,4 @@ INSERT INTO ofUser (username, plainPassword, name, email, creationDate, modifica
INSERT INTO ofMucService (serviceID, subdomain, isHidden) VALUES (1, 'conference', 0);

# Do this last, as it is used by a continuous integration check to verify that the entire script was executed successfully.
INSERT INTO ofVersion (name, version) VALUES ('openfire', 37);
INSERT INTO ofVersion (name, version) VALUES ('openfire', 38);
4 changes: 2 additions & 2 deletions distribution/src/database/openfire_oracle.sql
Original file line number Diff line number Diff line change
Expand Up @@ -199,7 +199,7 @@ CREATE TABLE ofMucRoom(
logEnabled INTEGER NOT NULL,
retireOnDeletion INTEGER NOT NULL,
preserveHistOnDel INTEGER NOT NULL,
subject VARCHAR2(100) NULL,
subject VARCHAR2(4000) NULL,
rolesToBroadcast INTEGER NOT NULL,
useReservedNick INTEGER NOT NULL,
canChangeNick INTEGER NOT NULL,
Expand Down Expand Up @@ -389,6 +389,6 @@ INSERT INTO ofUser (username, plainPassword, name, email, creationDate, modifica
INSERT INTO ofMucService (serviceID, subdomain, isHidden) VALUES (1, 'conference', 0);

-- Do this last, as it is used by a continuous integration check to verify that the entire script was executed successfully.
INSERT INTO ofVersion (name, version) VALUES ('openfire', 37);
INSERT INTO ofVersion (name, version) VALUES ('openfire', 38);

commit;
4 changes: 2 additions & 2 deletions distribution/src/database/openfire_postgresql.sql
Original file line number Diff line number Diff line change
Expand Up @@ -207,7 +207,7 @@ CREATE TABLE ofMucRoom (
logEnabled INTEGER NOT NULL,
retireOnDeletion INTEGER NOT NULL,
preserveHistOnDel INTEGER NOT NULL,
subject VARCHAR(100) NULL,
subject TEXT NULL,
rolesToBroadcast INTEGER NOT NULL,
useReservedNick INTEGER NOT NULL,
canChangeNick INTEGER NOT NULL,
Expand Down Expand Up @@ -397,4 +397,4 @@ INSERT INTO ofUser (username, plainPassword, name, email, creationDate, modifica
INSERT INTO ofMucService (serviceID, subdomain, isHidden) VALUES (1, 'conference', 0);

-- Do this last, as it is used by a continuous integration check to verify that the entire script was executed successfully.
INSERT INTO ofVersion (name, version) VALUES ('openfire', 37);
INSERT INTO ofVersion (name, version) VALUES ('openfire', 38);
4 changes: 2 additions & 2 deletions distribution/src/database/openfire_sqlserver.sql
Original file line number Diff line number Diff line change
Expand Up @@ -205,7 +205,7 @@ CREATE TABLE ofMucRoom (
logEnabled INT NOT NULL,
retireOnDeletion INT NOT NULL,
preserveHistOnDel INT NOT NULL,
subject NVARCHAR(100) NULL,
subject NTEXT NULL,
rolesToBroadcast INT NOT NULL,
useReservedNick INT NOT NULL,
canChangeNick INT NOT NULL,
Expand Down Expand Up @@ -394,4 +394,4 @@ INSERT INTO ofUser (username, plainPassword, name, email, creationDate, modifica
INSERT INTO ofMucService (serviceID, subdomain, isHidden) VALUES (1, 'conference', 0);

/* Do this last, as it is used by a continuous integration check to verify that the entire script was executed successfully. */
INSERT INTO ofVersion (name, version) VALUES ('openfire', 37);
INSERT INTO ofVersion (name, version) VALUES ('openfire', 38);
4 changes: 2 additions & 2 deletions distribution/src/database/openfire_sybase.sql
Original file line number Diff line number Diff line change
Expand Up @@ -204,7 +204,7 @@ CREATE TABLE ofMucRoom (
logEnabled INT NOT NULL,
retireOnDeletion INT NOT NULL,
preserveHistOnDel INT NOT NULL,
subject NVARCHAR(100) NULL,
subject TEXT NULL,
rolesToBroadcast INT NOT NULL,
useReservedNick INT NOT NULL,
canChangeNick INT NOT NULL,
Expand Down Expand Up @@ -394,4 +394,4 @@ INSERT INTO ofUser (username, plainPassword, name, email, creationDate, modifica
INSERT INTO ofMucService (serviceID, subdomain, isHidden) VALUES (1, 'conference', 0)

/* Do this last, as it is used by a continuous integration check to verify that the entire script was executed successfully. */
INSERT INTO ofVersion (name, version) VALUES ('openfire', 37)
INSERT INTO ofVersion (name, version) VALUES ('openfire', 38)
24 changes: 24 additions & 0 deletions distribution/src/database/upgrade/38/openfire_db2.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,24 @@
-- This copies the subject-defining stanza as stored in the message archive into the room's table, replacing any text
-- based (non-stanza) subject that was stored there.
-- In rare occasions (see OF-3131) the room can have a subject, while the history does not. In those cases, this script
-- leaves the (non-stanza) subject in the ofMucRoom table intact (this means that the column holds a mixture of plain
-- text and XMPP data).
-- Note that the stanzas in ofMucConversationLog typically do not contain a timestamp (although one is provided in a
-- separate column). If the subject that gets migrated to ofMucRoom is used as-is, the time of subject change is likely
-- lost (until the room's subject gets changed). This is deemed an acceptable loss.
ALTER TABLE ofMucRoom ALTER COLUMN subject SET DATA TYPE CLOB;

UPDATE ofMucRoom r
SET subject = (
SELECT stanza
FROM (
SELECT roomID, stanza,
ROW_NUMBER() OVER (PARTITION BY roomID ORDER BY logTime DESC) AS rn
FROM ofMucConversationLog
WHERE subject IS NOT NULL
) l
WHERE l.roomID = r.roomID
AND l.rn = 1
);

UPDATE ofVersion SET version = 38 WHERE name = 'openfire';
25 changes: 25 additions & 0 deletions distribution/src/database/upgrade/38/openfire_hsqldb.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
-- This copies the subject-defining stanza as stored in the message archive into the room's table, replacing any text
-- based (non-stanza) subject that was stored there.
-- In rare occasions (see OF-3131) the room can have a subject, while the history does not. In those cases, this script
-- leaves the (non-stanza) subject in the ofMucRoom table intact (this means that the column holds a mixture of plain
-- text and XMPP data).
-- Note that the stanzas in ofMucConversationLog typically do not contain a timestamp (although one is provided in a
-- separate column). If the subject that gets migrated to ofMucRoom is used as-is, the time of subject change is likely
-- lost (until the room's subject gets changed). This is deemed an acceptable loss.
ALTER TABLE ofMucRoom ALTER COLUMN subject SET DATA TYPE LONGVARCHAR;

UPDATE ofMucRoom r
SET r.subject = (
SELECT l.stanza
FROM ofMucConversationLog l
WHERE l.roomID = r.roomID
AND l.subject IS NOT NULL
AND l.logTime = (
SELECT MAX(l2.logTime)
FROM ofMucConversationLog l2
WHERE l2.roomID = r.roomID
AND l2.subject IS NOT NULL
)
);
Comment on lines 14 to 29
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

LLM complained that this might have many full table scans, and suggested using ROW_NUMBER like you did for Oracle. I've no experience here, but docs suggest that it's possible.

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

ROW_NUMBER in HSQLDB appears to have quirks. LLM suggests that we can use it only for this particular purpose after upgrading from 2.7.1 to 2.7.4 (which we may want to do anyways).

I do believe that the query can be improved for a roughly comparable performance improvement, but with something that's usable under 2.7.1. I have added a commit that has that improvement.


UPDATE ofVersion SET version = 38 WHERE name = 'openfire';
28 changes: 28 additions & 0 deletions distribution/src/database/upgrade/38/openfire_mysql.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,28 @@
-- This copies the subject-defining stanza as stored in the message archive into the room's table, replacing any text
-- based (non-stanza) subject that was stored there.
-- In rare occasions (see OF-3131) the room can have a subject, while the history does not. In those cases, this script
-- leaves the (non-stanza) subject in the ofMucRoom table intact (this means that the column holds a mixture of plain
-- text and XMPP data).
-- Note that the stanzas in ofMucConversationLog typically do not contain a timestamp (although one is provided in a
-- separate column). If the subject that gets migrated to ofMucRoom is used as-is, the time of subject change is likely
-- lost (until the room's subject gets changed). This is deemed an acceptable loss.
ALTER TABLE ofMucRoom MODIFY subject TEXT NULL;

UPDATE ofMucRoom r
JOIN (
SELECT l.roomID, l.stanza
FROM ofMucConversationLog l
JOIN (
SELECT roomID, MAX(logTime) AS maxTime
FROM ofMucConversationLog
WHERE subject IS NOT NULL
GROUP BY roomID
) latest
ON l.roomID = latest.roomID
AND l.logTime = latest.maxTime
) c
ON r.roomID = c.roomID
SET r.subject = c.stanza
WHERE c.stanza IS NOT NULL;

UPDATE ofVersion SET version = 38 WHERE name = 'openfire';
26 changes: 26 additions & 0 deletions distribution/src/database/upgrade/38/openfire_oracle.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,26 @@
-- This copies the subject-defining stanza as stored in the message archive into the room's table, replacing any text
-- based (non-stanza) subject that was stored there.
-- In rare occasions (see OF-3131) the room can have a subject, while the history does not. In those cases, this script
-- leaves the (non-stanza) subject in the ofMucRoom table intact (this means that the column holds a mixture of plain
-- text and XMPP data).
-- Note that the stanzas in ofMucConversationLog typically do not contain a timestamp (although one is provided in a
-- separate column). If the subject that gets migrated to ofMucRoom is used as-is, the time of subject change is likely
-- lost (until the room's subject gets changed). This is deemed an acceptable loss.
ALTER TABLE ofMucRoom MODIFY subject VARCHAR2(4000);

MERGE INTO ofMucRoom r
USING (
SELECT roomID, stanza
FROM (
SELECT roomID, stanza,
ROW_NUMBER() OVER (PARTITION BY roomID ORDER BY logTime DESC) AS rn
FROM ofMucConversationLog
WHERE subject IS NOT NULL
) t
WHERE rn = 1
) c
ON (r.roomID = c.roomID)
WHEN MATCHED THEN
UPDATE SET r.subject = c.stanza;

UPDATE ofVersion SET version = 38 WHERE name = 'openfire';
22 changes: 22 additions & 0 deletions distribution/src/database/upgrade/38/openfire_postgresql.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
-- This copies the subject-defining stanza as stored in the message archive into the room's table, replacing any text
-- based (non-stanza) subject that was stored there.
-- In rare occasions (see OF-3131) the room can have a subject, while the history does not. In those cases, this script
-- leaves the (non-stanza) subject in the ofMucRoom table intact (this means that the column holds a mixture of plain
-- text and XMPP data).
-- Note that the stanzas in ofMucConversationLog typically do not contain a timestamp (although one is provided in a
-- separate column). If the subject that gets migrated to ofMucRoom is used as-is, the time of subject change is likely
-- lost (until the room's subject gets changed). This is deemed an acceptable loss.
ALTER TABLE ofMucRoom ALTER COLUMN subject TYPE TEXT;

UPDATE ofMucRoom r
SET subject = c.stanza
FROM (
SELECT DISTINCT ON (roomID) roomID, stanza
FROM ofMucConversationLog
WHERE subject IS NOT NULL
ORDER BY roomID, logTime DESC
) c
WHERE c.roomID = r.roomID
AND c.stanza IS NOT NULL;

UPDATE ofVersion SET version = 38 WHERE name = 'openfire';
25 changes: 25 additions & 0 deletions distribution/src/database/upgrade/38/openfire_sqlserver.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
-- This copies the subject-defining stanza as stored in the message archive into the room's table, replacing any text
-- based (non-stanza) subject that was stored there.
-- In rare occasions (see OF-3131) the room can have a subject, while the history does not. In those cases, this script
-- leaves the (non-stanza) subject in the ofMucRoom table intact (this means that the column holds a mixture of plain
-- text and XMPP data).
-- Note that the stanzas in ofMucConversationLog typically do not contain a timestamp (although one is provided in a
-- separate column). If the subject that gets migrated to ofMucRoom is used as-is, the time of subject change is likely
-- lost (until the room's subject gets changed). This is deemed an acceptable loss.
ALTER TABLE ofMucRoom ALTER COLUMN subject NTEXT NULL;

WITH LatestLogs AS (
SELECT roomID, stanza,
ROW_NUMBER() OVER (PARTITION BY roomID ORDER BY logTime DESC) AS rn
FROM ofMucConversationLog
WHERE subject IS NOT NULL
)
UPDATE r
SET r.subject = l.stanza
FROM ofMucRoom r
JOIN LatestLogs l
ON r.roomID = l.roomID
WHERE l.rn = 1
AND l.stanza IS NOT NULL;

UPDATE ofVersion SET version = 38 WHERE name = 'openfire';
25 changes: 25 additions & 0 deletions distribution/src/database/upgrade/38/openfire_sybase.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
-- This copies the subject-defining stanza as stored in the message archive into the room's table, replacing any text
-- based (non-stanza) subject that was stored there.
-- In rare occasions (see OF-3131) the room can have a subject, while the history does not. In those cases, this script
-- leaves the (non-stanza) subject in the ofMucRoom table intact (this means that the column holds a mixture of plain
-- text and XMPP data).
-- Note that the stanzas in ofMucConversationLog typically do not contain a timestamp (although one is provided in a
-- separate column). If the subject that gets migrated to ofMucRoom is used as-is, the time of subject change is likely
-- lost (until the room's subject gets changed). This is deemed an acceptable loss.
ALTER TABLE ofMucRoom ALTER COLUMN subject TEXT NULL;

WITH LatestLogs AS (
SELECT roomID, stanza,
ROW_NUMBER() OVER (PARTITION BY roomID ORDER BY logTime DESC) AS rn
FROM ofMucConversationLog
WHERE subject IS NOT NULL
)
UPDATE r
SET r.subject = l.stanza
FROM ofMucRoom r
JOIN LatestLogs l
ON r.roomID = l.roomID
WHERE l.rn = 1
AND l.stanza IS NOT NULL;

UPDATE ofVersion SET version = 38 WHERE name = 'openfire';
Original file line number Diff line number Diff line change
Expand Up @@ -68,7 +68,7 @@ public class SchemaManager {
/**
* Current Openfire database schema version.
*/
private static final int DATABASE_VERSION = 37;
private static final int DATABASE_VERSION = 38;

/**
* Checks the Openfire database schema to ensure that it's installed and up to date.
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -88,7 +88,9 @@ public class HistoryStrategy implements Externalizable {

/**
* Track the latest room subject change or null if none exists yet.
* @deprecated Since Openfire 5.1.0, a room's subject is managed by {@link MUCRoom} directly.
*/
@Deprecated(forRemoval = true) // Remove in or after Openfire 5.2.0
private Message roomSubject = null;

/**
Expand Down Expand Up @@ -434,7 +436,9 @@ public void setContext(String subdomain, String prefix) {
*
* @return true if there is a message within the history of the room that has changed the
* room's subject.
* @deprecated Since Openfire 5.1.0, a room's subject is managed by {@link MUCRoom} directly.
*/
@Deprecated(forRemoval = true) // Remove in or after Openfire 5.2.0
public boolean hasChangedSubject() {
return roomSubject != null;
}
Expand All @@ -444,7 +448,9 @@ public boolean hasChangedSubject() {
* room's subject.
*
* @return the latest room subject change or null if none exists yet.
* @deprecated Since Openfire 5.1.0, a room's subject is managed by {@link MUCRoom} directly.
*/
@Deprecated(forRemoval = true) // Remove in or after Openfire 5.2.0
@Nullable
public Message getChangedSubject() {
return roomSubject;
Expand Down
Loading
Loading