diff --git a/UPGRADE.md b/UPGRADE.md index 117b4bff..f87c2079 100644 --- a/UPGRADE.md +++ b/UPGRADE.md @@ -39,6 +39,13 @@ Report your issue on Xibalba BBS, hop in #enigma-bbs on FreeNode and chat, or ] } ``` +* A set of database fixes were made that cause some records to be properly cleaned up when e.g. deleting a file. Existing `file.db` databases will need to be updated **manually**. Note that this applies to users upgrading within 0.0.12-beta as well: +1. **Make a backup of your file.db!** +2. Shut down ENiGMA. +3. From the enigma-bbs directory: +``` +sqlite3 db/file.sqlite3 < ./misc/update/tables_update_2020-11-29.sql +``` # 0.0.10-alpha to 0.0.11-beta * Node.js 12.x LTS is now in use. Follow standard Node.js upgrade procedures (e.g.: `nvm install 12 && nvm use 12`). diff --git a/WHATSNEW.md b/WHATSNEW.md index 51594b04..c249ea65 100644 --- a/WHATSNEW.md +++ b/WHATSNEW.md @@ -12,6 +12,9 @@ This document attempts to track **major** changes and additions in ENiGMA½. For * Added ability to export/download messages. This is enabled in the default menu. See `messageAreaViewPost` in [the default message base template](./misc/menu_templates/message_base.in.hjson) and look for the download options (`@method:addToDownloadQueue`, etc.) for details on adding to your system! * The Gopher server has had a revamp! Standard `gophermap` files are now served along with any other content you configure for your Gopher Hole! A default [gophermap](https://en.wikipedia.org/wiki/Gopher_(protocol)#Source_code_of_a_menu) can be found [in the misc directory](./misc/gophermap) that behaves like the previous implementation. See [Gopher docs](./docs/servers/gopher.md) for more information. * Default file browser up/down/pageUp/pageDown scrolls description (e.g. FILE_ID.DIZ). If you want to expose this on an existing system see the `fileBaseListEntries` in the default `file_base.in.hjson` template. +* File base search has had an improvement to search term handling. +* `./oputil user group -group` to now accepts `~group` removing the need for special handling of the "-" character. #331 +* A fix has been made to clean up old `file.db` entries when a file is removed. Previously stale records could be left or even recycled into new entries. Please see [UPGRADE.md](UPGRADE.md) for details on applying this fix (look for `tables_update_2020-11-29.sql`). ## 0.0.11-beta * Upgraded from `alpha` to `beta` -- The software is far along and mature enough at this point! diff --git a/core/database.js b/core/database.js index 17bc3844..55ed4e2e 100644 --- a/core/database.js +++ b/core/database.js @@ -421,7 +421,8 @@ const DB_INIT_TABLE = { hash_tag_id INTEGER NOT NULL, file_id INTEGER NOT NULL, - UNIQUE(hash_tag_id, file_id) + UNIQUE(hash_tag_id, file_id), + FOREIGN KEY(file_id) REFERENCES file(file_id) ON DELETE CASCADE );` ); @@ -431,7 +432,10 @@ const DB_INIT_TABLE = { user_id INTEGER NOT NULL, rating INTEGER NOT NULL, - UNIQUE(file_id, user_id) + UNIQUE(file_id, user_id), + FOREIGN KEY(file_id) REFERENCES file(file_id) ON DELETE CASCADE + -- Note that we cannot CASCADE if user_id is removed from user.db + -- See processing in oputil's removeUser() );` ); @@ -447,7 +451,8 @@ const DB_INIT_TABLE = { hash_id VARCHAR NOT NULL, file_id INTEGER NOT NULL, - UNIQUE(hash_id, file_id) + UNIQUE(hash_id, file_id), + FOREIGN KEY(file_id) REFERENCES file(file_id) ON DELETE CASCADE );` ); diff --git a/core/file_area_list.js b/core/file_area_list.js index 12abfd0d..637c3c3e 100644 --- a/core/file_area_list.js +++ b/core/file_area_list.js @@ -204,7 +204,7 @@ exports.getModule = class FileAreaList extends MenuModule { }, function display(callback) { return self.displayBrowsePage(false, err => { - if(err && 'NORESULTS' === err.reasonCode) { + if(err) { self.gotoMenu(self.menuConfig.config.noResultsMenu || 'fileBaseListEntriesNoResults'); } return callback(err); @@ -740,7 +740,7 @@ exports.getModule = class FileAreaList extends MenuModule { } FileEntry.findFiles(filterCriteria, (err, fileIds) => { - this.fileList = fileIds; + this.fileList = fileIds || []; return cb(err); }); } diff --git a/core/file_entry.js b/core/file_entry.js index 0539f137..476864ca 100644 --- a/core/file_entry.js +++ b/core/file_entry.js @@ -243,6 +243,15 @@ module.exports = class FileEntry { ); } + static removeUserRatings(userId, cb) { + return fileDb.run( + `DELETE FROM file_user_rating + WHERE user_id = ?;`, + [ userId ], + cb + ); + } + static persistMetaValue(fileId, name, value, transOrDb, cb) { if(!_.isFunction(cb) && _.isFunction(transOrDb)) { cb = transOrDb; @@ -457,6 +466,16 @@ module.exports = class FileEntry { ); } + // + // Find file(s) by |filter| + // + // - sort: sort results by any well known name, file_id, or user_rating + // - terms: one or more search terms to search within filenames as well + // as short and long descriptions. We attempt to use the FTS ability when + // possible, but want to allow users to search for wildcard matches in + // which some cases we'll use multiple LIKE queries. + // See _normalizeFileSearchTerms() + // static findFiles(filter, cb) { filter = filter || {}; @@ -500,8 +519,8 @@ module.exports = class FileEntry { if('user_rating' === filter.sort) { sql = `SELECT DISTINCT f.file_id, - (SELECT IFNULL(AVG(rating), 0) rating - FROM file_user_rating + (SELECT IFNULL(AVG(rating), 0) rating + FROM file_user_rating WHERE file_id = f.file_id) AS avg_rating FROM file f`; @@ -540,16 +559,16 @@ module.exports = class FileEntry { mp.value = mp.value.replace(/\*/g, '%').replace(/\?/g, '_'); appendWhereClause( `f.file_id IN ( - SELECT file_id - FROM file_meta + SELECT file_id + FROM file_meta WHERE meta_name = "${mp.name}" AND meta_value LIKE "${mp.value}" )` ); } else { appendWhereClause( `f.file_id IN ( - SELECT file_id - FROM file_meta + SELECT file_id + FROM file_meta WHERE meta_name = "${mp.name}" AND meta_value = "${mp.value}" )` ); @@ -562,14 +581,29 @@ module.exports = class FileEntry { } if(filter.terms && filter.terms.length > 0) { - // note the ':' in MATCH expr., see https://www.sqlite.org/cvstrac/wiki?p=FullTextIndex - appendWhereClause( - `f.file_id IN ( - SELECT rowid - FROM file_fts - WHERE file_fts MATCH ":${sanitizeString(filter.terms)}" - )` - ); + const [terms, queryType] = FileEntry._normalizeFileSearchTerms(filter.terms); + + if ('fts_match' === queryType) { + // note the ':' in MATCH expr., see https://www.sqlite.org/cvstrac/wiki?p=FullTextIndex + appendWhereClause( + `f.file_id IN ( + SELECT rowid + FROM file_fts + WHERE file_fts MATCH ":${terms}" + )` + ); + } else { + appendWhereClause( + `(f.file_name LIKE "${terms}" OR + f.desc LIKE "${terms}" OR + f.desc_long LIKE "${terms}")` + ); + } + } + + // handle e.g. 1998 -> "1998" + if (_.isNumber(filter.tags)) { + filter.tags = filter.tags.toString(); } if(filter.tags && filter.tags.length > 0) { @@ -693,4 +727,46 @@ module.exports = class FileEntry { } ); } + + static _normalizeFileSearchTerms(terms) { + // ensure we have reasonable input to start with + terms = sanitizeString(terms.toString()); + + // No wildcards? + const hasSingleCharWC = terms.indexOf('?') > -1; + if (terms.indexOf('*') === -1 && !hasSingleCharWC) { + return [ terms, 'fts_match' ]; + } + + const prepareLike = () => { + // Convert * and ? to SQL LIKE style + terms = terms.replace(/\*/g, '%').replace(/\?/g, '_'); + return terms; + }; + + // Any ? wildcards? + if (hasSingleCharWC) { + return [ prepareLike(terms), 'like' ]; + } + + const split = terms.replace(/\s+/g, ' ').split(' '); + const useLike = split.some(term => { + if (term.indexOf('?') > -1) { + return true; + } + + const wcPos = term.indexOf('*'); + if (wcPos > -1 && wcPos !== term.length - 1) { + return true; + } + + return false; + }); + + if (useLike) { + return [ prepareLike(terms), 'like' ]; + } + + return [ terms, 'fts_match' ]; + } }; diff --git a/core/oputil/oputil_help.js b/core/oputil/oputil_help.js index 50bc3b5e..05025cfe 100644 --- a/core/oputil/oputil_help.js +++ b/core/oputil/oputil_help.js @@ -57,7 +57,7 @@ Actions: lock USERNAME Set a user's status to "locked" - group USERNAME [+|-]GROUP Adds (+) or removes (-) user from a group + group USERNAME [+|~]GROUP Adds (+) or removes (~) user from a group list [FILTER] List users with optional FILTER. diff --git a/core/oputil/oputil_user.js b/core/oputil/oputil_user.js index 403c5076..d3a13931 100644 --- a/core/oputil/oputil_user.js +++ b/core/oputil/oputil_user.js @@ -172,6 +172,7 @@ function removeUser(user) { message : [ 'user_message_area_last_read' ], system : [ 'user_event_log', ], user : [ 'user_group_member', 'user' ], + file : [ 'file_user_rating'] }; async.eachSeries(Object.keys(DeleteFrom), (dbName, nextDbName) => { @@ -275,7 +276,7 @@ function modUserGroups(user) { let groupName = argv._[argv._.length - 1].toString().replace(/["']/g, ''); // remove any quotes - necessary to allow "-foo" let action = groupName[0]; // + or - - if('-' === action || '+' === action) { + if('-' === action || '+' === action || '~' === action) { groupName = groupName.substr(1); } @@ -286,7 +287,7 @@ function modUserGroups(user) { } // - // Groups are currently arbritary, so do a slight validation + // Groups are currently arbitrary, so do a slight validation // if(!/[A-Za-z0-9]+/.test(groupName)) { process.exitCode = ExitCodes.BAD_ARGS; @@ -303,7 +304,7 @@ function modUserGroups(user) { } const UserGroup = require('../../core/user_group.js'); - if('-' === action) { + if('-' === action || '~' === action) { UserGroup.removeUserFromGroup(user.userId, groupName, done); } else { UserGroup.addUserToGroup(user.userId, groupName, done); diff --git a/docs/admin/oputil.md b/docs/admin/oputil.md index 49e7039c..b2ee2892 100644 --- a/docs/admin/oputil.md +++ b/docs/admin/oputil.md @@ -76,7 +76,16 @@ Actions: lock USERNAME Set a user's status to "locked" - group USERNAME [+|-]GROUP Adds (+) or removes (-) user from a group + group USERNAME [+|~]GROUP Adds (+) or removes (~) user from a group + + list [FILTER] List users with optional FILTER. + + Valid filters: + all : All users (default). + disabled : Disabled users. + inactive : Inactive users. + active : Active (regular) users. + locked : Locked users. info arguments: --security Include security information in output @@ -104,7 +113,7 @@ info arguments: | `deactivate` | Deactivates user | `./oputil.js user deactivate joeuser` | N/A | | `disable` | Disables user (user will not be able to login) | `./oputil.js user disable joeuser` | N/A | | `lock` | Locks the user account (prevents logins) | `./oputil.js user lock joeuser` | N/A | -| `group` | Modifies users group membership | Add to group: `./oputil.js user group joeuser +derp`
Remove from group: `./oputil.js user group joeuser -derp` | N/A | +| `group` | Modifies users group membership | Add to group: `./oputil.js user group joeuser +derp`
Remove from group: `./oputil.js user group joeuser ~derp` | N/A | #### Manage 2FA/OTP While `oputil.js` can be used to manage a user's 2FA/OTP, it is highly recommended to require users to opt-in themselves. See [Security](../configuration/security.md) for details. diff --git a/misc/update/tables_update_2020-11-29.sql b/misc/update/tables_update_2020-11-29.sql new file mode 100644 index 00000000..7d8ac862 --- /dev/null +++ b/misc/update/tables_update_2020-11-29.sql @@ -0,0 +1,41 @@ +PRAGMA foreign_keys=OFF; + +BEGIN; + +CREATE TABLE IF NOT EXISTS file_hash_tag_new ( + hash_tag_id INTEGER NOT NULL, + file_id INTEGER NOT NULL, + + UNIQUE(hash_tag_id, file_id), + FOREIGN KEY(file_id) REFERENCES file(file_id) ON DELETE CASCADE +); +INSERT INTO file_hash_tag_new SELECT * FROM file_hash_tag; +DROP TABLE file_hash_tag; +ALTER TABLE file_hash_tag_new RENAME TO file_hash_tag; + +CREATE TABLE IF NOT EXISTS file_user_rating_new ( + file_id INTEGER NOT NULL, + user_id INTEGER NOT NULL, + rating INTEGER NOT NULL, + + UNIQUE(file_id, user_id), + FOREIGN KEY(file_id) REFERENCES file(file_id) ON DELETE CASCADE +); +INSERT INTO file_user_rating_new SELECT * FROM file_user_rating; +DROP TABLE file_user_rating; +ALTER TABLE file_user_rating_new RENAME TO file_user_rating; + +CREATE TABLE IF NOT EXISTS file_web_serve_batch_new ( + hash_id VARCHAR NOT NULL, + file_id INTEGER NOT NULL, + + UNIQUE(hash_id, file_id), + FOREIGN KEY(file_id) REFERENCES file(file_id) ON DELETE CASCADE +); +INSERT INTO file_web_serve_batch_new SELECT * FROM file_web_serve_batch; +DROP TABLE file_web_serve_batch; +ALTER TABLE file_web_serve_batch_new RENAME TO file_web_serve_batch; + +PRAGMA foreign_key_check; +COMMIT; +PRAGMA foreign_keys=ON;