├── .gitignore ├── package.json ├── LICENSE ├── test.js ├── README.md └── index.js /.gitignore: -------------------------------------------------------------------------------- 1 | /@* -------------------------------------------------------------------------------- /package.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "liquery", 3 | "version": "0.10.0", 4 | "description": "Powerful search, tagging, filtering and sorting via simple text query language, for SQLite databases", 5 | "main": "index.js", 6 | "scripts": { 7 | "test": "node test.js" 8 | }, 9 | "homepage": "https://github.com/haxtra/liquery", 10 | "repository": "github:haxtra/liquery", 11 | "keywords": [ 12 | "tags", 13 | "tagging", 14 | "query", 15 | "sql", 16 | "sqlite" 17 | ], 18 | "author": "Hax ", 19 | "license": "MIT" 20 | } -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2023 haxtra 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /test.js: -------------------------------------------------------------------------------- 1 | const assert = require('assert') 2 | const Equal = assert.strict.equal 3 | const LiQuery = require('./') 4 | 5 | let query, q, o; 6 | 7 | // === Full: all features ================================= 8 | 9 | query = ` 10 | kword tag1 tag2 tagor1|tagor2 !tagnot 11 | aliased:yes 12 | illegal:yes 13 | equal:1 gt>2 lt<3 gte:>4 lte:<5 noteq!6 nil:null 14 | range:1-9 15 | multi:123,abc,0x86 16 | multi_neg!abc,0x86,123 17 | numbers:asc letters:desc 18 | ` 19 | q = new LiQuery({ 20 | table: "my_table", 21 | primary: "id", 22 | search: "my_search", 23 | default: "deftag id:asc", 24 | 25 | select: ["id","name","beans"], 26 | count: ["COUNT(id) AS count", "SUM(beans) AS beans"], 27 | 28 | keywords: { 29 | kword: "foo:1 bar:2", 30 | }, 31 | aliases: { 32 | aliased: "super_long_name", 33 | }, 34 | processors: { 35 | super_long_name: val => val == "yes" ? 1 : 0 36 | }, 37 | allowed: [ 38 | "aliased", "equal", "gt", "lt", "gte", "lte", "noteq", "nil", "range", "multi", "multi_neg", 39 | "numbers", "letters", "foo", "bar", "id" 40 | ], 41 | scope: "sqlfield=123", 42 | 43 | debug: true, 44 | }) 45 | 46 | o = q.parse(query + " @5") 47 | 48 | 49 | Equal(q.table, "my_table") 50 | Equal(q.search, "my_search") 51 | Equal(q.primary, "id") 52 | Equal(q.default, "deftag id:asc") 53 | Equal(q.keywords.kword, "foo:1 bar:2") 54 | Equal(q.aliases.aliased, "super_long_name") 55 | Equal(q.allowed.length, 16) 56 | 57 | Equal(q.select[0], "id") 58 | Equal(q.select[1], "name") 59 | Equal(q.select[2], "beans") 60 | 61 | Equal(q.count[0], "COUNT(id) AS count") 62 | Equal(q.count[1], "SUM(beans) AS beans") 63 | 64 | Equal(o.where[0], "sqlfield=123") 65 | Equal(o.where[1], "my_search LIKE '%tag1%'") 66 | Equal(o.where[2], "my_search LIKE '%tag2%'") 67 | Equal(o.where[3], "(my_search LIKE '%tagor1%' OR my_search LIKE '%tagor2%')") 68 | Equal(o.where[4], "my_search NOT LIKE '%tagnot%'") 69 | Equal(o.where[5], "my_search LIKE '%deftag%'") 70 | Equal(o.where[6], "super_long_name = 1") 71 | Equal(o.where[7], "equal = 1") 72 | Equal(o.where[8], "gt > 2") 73 | Equal(o.where[9], "gte >= 4") 74 | Equal(o.where[10], "lt < 3") 75 | Equal(o.where[11], "lte <= 5") 76 | Equal(o.where[12], "multi IN (123,'abc',0x86)") 77 | Equal(o.where[13], "multi_neg NOT IN ('abc',0x86,123)") 78 | Equal(o.where[14], "nil ISNULL") 79 | Equal(o.where[15], "noteq != 6") 80 | Equal(o.where[16], "range BETWEEN 1 AND 9") 81 | Equal(o.where[17], "foo = 1") 82 | Equal(o.where[18], "bar = 2") 83 | 84 | Equal(o.limit, 100) 85 | Equal(o.offset, 400) 86 | Equal(o.page, 5) 87 | Equal(o.pages(12345), 124) 88 | 89 | Equal(o.sql.count, 90 | "SELECT COUNT(id) AS count, SUM(beans) AS beans FROM my_table WHERE " + 91 | "sqlfield=123 AND my_search LIKE '%tag1%' AND my_search LIKE '%tag2%' " + 92 | "AND (my_search LIKE '%tagor1%' OR my_search LIKE '%tagor2%') AND " + 93 | "my_search NOT LIKE '%tagnot%' AND my_search LIKE '%deftag%' AND " + 94 | "super_long_name = 1 AND equal = 1 AND gt > 2 AND gte >= 4 AND lt < 3 " + 95 | "AND lte <= 5 AND multi IN (123,'abc',0x86) AND multi_neg NOT IN " + 96 | "('abc',0x86,123) AND nil ISNULL AND noteq != 6 AND range BETWEEN 1 AND 9 " + 97 | "AND foo = 1 AND bar = 2") 98 | 99 | Equal(o.sql.select, 100 | "SELECT id, name, beans FROM my_table WHERE sqlfield=123 AND " + 101 | "my_search LIKE '%tag1%' AND my_search LIKE '%tag2%' AND (my_search " + 102 | "LIKE '%tagor1%' OR my_search LIKE '%tagor2%') AND my_search NOT " + 103 | "LIKE '%tagnot%' AND my_search LIKE '%deftag%' AND super_long_name " + 104 | "= 1 AND equal = 1 AND gt > 2 AND gte >= 4 AND lt < 3 AND lte <= 5 " + 105 | "AND multi IN (123,'abc',0x86) AND multi_neg NOT IN ('abc',0x86,123) " + 106 | "AND nil ISNULL AND noteq != 6 AND range BETWEEN 1 AND 9 AND foo = " + 107 | "1 AND bar = 2 ORDER BY numbers ASC, letters DESC LIMIT 100 OFFSET " + 108 | "400") 109 | 110 | Equal(o.errors.length, 1) 111 | Equal(o.errors[0], "illegal") 112 | 113 | 114 | // === Full: random sort ================================== 115 | 116 | o = q.parse(query + " random", {page:22}) 117 | 118 | Equal(o.sql.select.indexOf("ORDER BY RANDOM()"), 471) 119 | Equal(o.page, 22) 120 | Equal(o.offset, 2100) 121 | 122 | 123 | // === Full: parse scope ================================== 124 | 125 | o = q.parse(query + " random", {scope:"foo='bar'", page:10, limit:20}) 126 | 127 | Equal(o.where[0], "sqlfield=123") 128 | Equal(o.where[1], "foo='bar'") 129 | Equal(o.limit, 20) 130 | Equal(o.sql.select.indexOf("LIMIT 20 OFFSET 180"), 503) 131 | 132 | 133 | // === Blank query ======================================== 134 | 135 | q = new LiQuery({ 136 | table: "my_table", 137 | }) 138 | 139 | o = q.parse() 140 | 141 | Equal(q.table, "my_table") 142 | Equal(q.search, "search") 143 | Equal(o.sql.select, "SELECT * FROM my_table LIMIT 100 OFFSET 0") 144 | Equal(o.sql.count, "SELECT COUNT(id) AS count FROM my_table ") 145 | Equal(o.page, 1) 146 | Equal(o.offset, 0) 147 | 148 | 149 | console.log("\n ✔ All tests passed.\n") 150 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # LiQuery 2 | 3 | Powerful search, tagging, filtering and sorting via simple text query language, for SQLite databases. 4 | 5 | 10kb maximized, no dependencies. 6 | 7 | 8 | ## Example 9 | 10 | hq hammond rock|metal !jazz type:mp3 year:1970-1980 rating:desc 11 | 12 | Translates to: 13 | 14 | ```sql 15 | SELECT * FROM music 16 | WHERE search LIKE '%hammond%' 17 | AND (search LIKE '%rock%' OR search LIKE '%metal%') 18 | AND search NOT LIKE '%jazz%' 19 | AND type='mp3' 20 | AND year BETWEEN 1970 AND 1980 21 | AND bitrate=320 -- preset from `hq` keyword 22 | AND sampling=44.1 -- preset from `hq` keyword 23 | ORDER BY rating DESC 24 | LIMIT 100 OFFSET 0 25 | ``` 26 | 27 | 28 | ## Reference 29 | 30 | keyword tag tag|tag !tag equal:1 greater>2 equalgt:>3 not!equal nil:null range:1-5 multi:1,a,x multineg!1,a,x sort:desc @2 31 | 32 | \s or + separator 33 | keyword expands to predefined subquery 34 | tag like 35 | tag tag like and like 36 | tag|tag like or like 37 | !tag not like 38 | field:3 equal 39 | field!3 not equal 40 | field>3 less/greater 41 | field:>3 less/greater equal 42 | field:null null 43 | field:1,3 multi value, positive 44 | field!1,3 multi value, negative 45 | field:1-3 numeric range, inclusive 46 | field:asc sort asc/desc 47 | random random sort 48 | @2 result page number 49 | 50 | 51 | ## Database prerequisites 52 | 53 | For tags/search, table must provide search field with content to be searched. 54 | 55 | Tags and search terms are technically the same thing, the difference is semantic and depends on what you put in your search field, data, metadata, or both. 56 | 57 | 58 | ## Install 59 | 60 | npm i liquery 61 | 62 | 63 | ## Usage 64 | 65 | ```js 66 | // import 67 | const LiQuery = require('liquery') 68 | 69 | // create and configure instance 70 | const liquery = new LiQuery({ 71 | table: "table_name" 72 | }) 73 | 74 | // parse query 75 | const q = liquery.parse(queryText) 76 | // q.query -- canonical query, cleaned and normalized user query string 77 | // q.input -- original user query, perhaps dirty 78 | // q.sql.select -- generated sql query for record retrieval 79 | // q.sql.count -- generated sql query for record count and stats 80 | // q.page -- result page number 81 | // q.pages(count) -- calculated number of pages, based on the number of records 82 | // q.errors -- occurred query processing errors 83 | 84 | // now, with your SQLite driver of choice: 85 | const items = db.query(q.sql.select) 86 | const stats = db.query(q.sql.count) 87 | ``` 88 | 89 | 90 | ## Config 91 | 92 | Instance config 93 | 94 | ```js 95 | const query = new LiQuery({ // showing defaults 96 | 97 | table: null, // table name to query, the only required config param 98 | primary: "id", // primary key column name (used only for default count) 99 | search: "search", // search column name 100 | scope: null, // SQL expression to narrow scope (ex user_id=1), used for every query 101 | 102 | select: ["*"], // fields to pull on select query 103 | count: // stats to include in count query, sum, avg, etc 104 | ["COUNT(id) AS count"], 105 | limit: 100, // limit retrieved records 106 | 107 | default: null, // default query, see section below 108 | keywords: {}, // shortcuts that expand to sub queries 109 | aliases: {}, // field name aliases for use with filters and sorting 110 | processors: {}, // functions that transform filter values for SQL generation 111 | allowed: null, // list of fields that can be filtered and sorted on 112 | 113 | debug: false // dump processing errors to console 114 | // keep intermediate object attached to result object 115 | }) 116 | ``` 117 | 118 | Request config 119 | 120 | ```js 121 | query.parse(queryText, { 122 | page: 1, // result page, but `@` from user query have precedence 123 | limit: 100, // overrides instance config value 124 | scope: null, // SQL expression, in addition to scope from instance config 125 | }) 126 | ``` 127 | 128 | 129 | ### Default query 130 | 131 | Default query in LiQuery format. If provided, will be applied in part, or full to each user query. Rules to follow: 132 | 133 | keywords -- cannot be used in default query 134 | tags -- always included, even if negated by user query 135 | filter -- included if not overridden by user query, per field basis 136 | sort -- used if user query does not specify sort 137 | 138 | 139 | ### Keywords 140 | 141 | Keywords are like presets, they expand into subqueries. LiQuery format. 142 | 143 | ```js 144 | keywords: { 145 | top: "rating:desc", 146 | best: "rating:4-6", 147 | hq: "bitrate:320 sampling:44.1", 148 | } 149 | ``` 150 | 151 | Note that keywords cannot be negated, negated keyword `!keyword` will be treated just like a normal tag. 152 | 153 | 154 | ### Aliases 155 | 156 | Aliases are used with db fields (filters and sort) to shorten or change name of the field. 157 | 158 | ```js 159 | aliases: { 160 | id: "user", 161 | user_status: "status", 162 | user_last_seen: "seen", 163 | } 164 | ``` 165 | 166 | > user:1337 167 | > status:1 168 | > seen:desc 169 | 170 | 171 | ### Processors 172 | 173 | Functions that transform filter values for SQL generation. Useful if we have for example `user_status` column that uses numerical ids, and we want to query it using status names. Note that fields must use real names, not aliases. 174 | 175 | ```js 176 | // some lookup object 177 | const userStatus = { 178 | inactive: 0, 179 | active: 1, 180 | } 181 | 182 | // processor directives 183 | processors: { 184 | user_status: value => userStatus[value] 185 | } 186 | ``` 187 | // using with alias 188 | status:active 189 | 190 | // SQL 191 | ...WHERE user_status = 1 192 | 193 | 194 | ### Scope 195 | 196 | SQL expression to narrow down the results. Only used for generated `SELECT` and `COUNT` queries. 197 | Scope defined in instance config will be included in every query, additional scope can be added on per request basis. 198 | 199 | // use literal strings 200 | "user_id=1 AND status=2" 201 | 202 | 203 | ### Allowed 204 | 205 | List of database columns that are allowed to be used for filter and sort. Fields from query that are not listed in `.allowed` or `.aliases` will be dropped from the query. Default value `null` disables enforcement, but will lead to database errors when trying to query non-existent db columns. 206 | 207 | 208 | ## Caveats 209 | 210 | - no joins (this may change in the future) 211 | - no spaces in tags or values 212 | - uses `LIKE` operator, which might not be super performant on very large dataset 213 | - uses `%` wildcard operator, so search for `foo` will pull `foobar` too 214 | - probably more 215 | 216 | 217 | ![](https://hello.haxtra.com/gh-liquery) 218 | -------------------------------------------------------------------------------- /index.js: -------------------------------------------------------------------------------- 1 | "use strict" 2 | 3 | class LiQuery { 4 | 5 | table = null 6 | primary = 'id' 7 | search = 'search' 8 | 9 | default = null 10 | keywords = {} 11 | aliases = {} 12 | processors = {} 13 | allowed = null 14 | 15 | select = ["*"] 16 | count = [`COUNT(${this.primary}) AS count`] 17 | limit = 100 18 | 19 | scope = null // sql filter to narrow scope 20 | 21 | debug = false 22 | 23 | 24 | constructor(params={}) { 25 | 26 | // configuration 27 | for(const key in params) 28 | this[key] = params[key] 29 | } 30 | 31 | createContainer(opts) { 32 | 33 | return { 34 | input: null, 35 | query: null, 36 | sql: { 37 | select: null, 38 | count: null, 39 | }, 40 | page: opts.page || 1, 41 | pages: function(count) { return Math.ceil(count / this.limit) }, 42 | offset: 0, 43 | limit: opts.limit || this.limit, 44 | 45 | errors: [], 46 | 47 | // internal 48 | parsed: { 49 | query: { // user query 50 | keywords: [], 51 | tags: [], 52 | tagsOr: [], 53 | tagsNot: [], 54 | filters: [], 55 | sort: [], 56 | }, 57 | keywords: { // expanded keywords 58 | tags: [], 59 | tagsOr : [], 60 | tagsNot: [], 61 | filters: [], 62 | sort: [], 63 | }, 64 | default: { // defaults 65 | tags: [], 66 | tagsOr : [], 67 | tagsNot: [], 68 | filters: [], 69 | sort: [], 70 | } 71 | }, 72 | } 73 | } 74 | 75 | parse(query, opts={}) { 76 | /** Process supplied input. We can reuse configured instance by passing new query **/ 77 | 78 | const obj = this.createContainer(opts) 79 | 80 | obj.query = query 81 | obj.input = query // store original 82 | 83 | // process user query 84 | if(obj.query){ 85 | // clean input 86 | obj.query = obj.query 87 | .replace(/\+/g, ' ') // replace + for space, for when it comes from the url 88 | .replace(/\s+/g, ' ') // remove extra whitespace 89 | .trim() // remove leading/trailing spaces 90 | 91 | this.processPart(obj, obj.query, obj.parsed.query, this.keywords, true) 92 | } 93 | 94 | // expand and process keywords 95 | for(const keyword of obj.parsed.query.keywords) 96 | this.processPart(obj, this.keywords[keyword], obj.parsed.keywords) 97 | 98 | // process resource default 99 | if(this.default) 100 | this.processPart(obj, this.default, obj.parsed.default) 101 | 102 | // normalize query, put valid parts in right order 103 | this.normalize(obj) 104 | 105 | // generate clean, canonical query 106 | this.generateQuery(obj) 107 | 108 | // generate sql statements 109 | this.generateSQL(obj, opts) 110 | 111 | // drop internal fields 112 | if(!this.debug) 113 | delete obj.parsed 114 | 115 | // dump errors, if any 116 | if(this.debug && obj.errors.length) 117 | console.error('LiQuery errors:', obj.errors) 118 | 119 | return obj 120 | } 121 | 122 | processPart(obj, input, container, keywords={}, dedupe) { 123 | 124 | // split to parts and figure their type 125 | let parts = input.split(' ') 126 | 127 | // remove duplicates, only for user query 128 | if(dedupe) 129 | parts = parts.filter( (value, index, self) => self.indexOf(value) === index ) 130 | 131 | // verify that field use is allowed 132 | const useField = field => this.allowed ? (this.allowed.includes(field) || this.aliases[field] ? true : false) : true 133 | 134 | // identify parts of the query and put them to relevant buckets 135 | let match = false 136 | for(const part of parts){ 137 | 138 | // skip empty 139 | if(part == ''){ 140 | continue 141 | } 142 | // random sort 143 | else if(part == 'random'){ 144 | container.sort.push({order:'random'}) 145 | } 146 | // sort type 147 | else if(match = part.match(/([a-z0-9_]+):(asc|desc)/)){ 148 | if(useField(match[1])) 149 | container.sort.push({ 150 | field: match[1], 151 | order: match[2] 152 | }) 153 | else 154 | obj.errors.push(match[1]) 155 | } 156 | // filter: range type (numeric only) 157 | else if(match = part.match(/([a-z0-9_]+):([0-9\.]+)-([0-9\.]+)/)){ 158 | if(useField(match[1])) 159 | container.filters.push({ 160 | field: match[1], 161 | operator: '-', 162 | value: [match[2], match[3]], 163 | }) 164 | else 165 | obj.errors.push(match[1]) 166 | } 167 | // filter: value type, eqal|not equal 168 | else if(match = part.match(/([a-z0-9_]+)(:|!)([a-z0-9-_/\.,\{\}]+)/)){ 169 | if(useField(match[1])) 170 | container.filters.push({ 171 | field: match[1], 172 | operator: match[2], 173 | // multivalue? 174 | value: match[3].includes(',') ? match[3].split(',') : match[3], 175 | }) 176 | else 177 | obj.errors.push(match[1]) 178 | } 179 | // filter: value type, less, greater 180 | else if(match = part.match(/([a-z0-9_]+)(<|>|:<|:>)([a-z0-9-_/\.\{\}]+)/)){ // comma is reserved 181 | if(useField(match[1])) 182 | container.filters.push({ 183 | field: match[1], 184 | operator: match[2], 185 | value: match[3], 186 | }) 187 | else 188 | obj.errors.push(match[1]) 189 | } 190 | // keyword 191 | else if(keywords[part]){ 192 | container.keywords.push(part) 193 | } 194 | // tag - or 195 | else if(match = part.match(/\|/)){ 196 | // split on | and remove empty elems, in case of bad input 197 | const or_parts = part.split('|').filter(Boolean) 198 | if(or_parts.length > 1) 199 | container.tagsOr.push(or_parts) 200 | else if(or_parts.length > 0) 201 | container.tags.push(or_parts[0]) 202 | } 203 | // tag - inclusive or negated 204 | else if(match = part.match(/^(!?)([a-z0-9\.]+)$/)){ 205 | if(match[1]){ 206 | // negated tag 207 | container.tagsNot.push(match[2]) 208 | } else { 209 | // inclusive tag 210 | container.tags.push(match[2]) 211 | } 212 | } 213 | // page number 214 | else if(match = part.match(/^@(\d+)$/)){ 215 | obj.page = parseInt(match[1]) 216 | } 217 | else { 218 | obj.errors.push(part) 219 | } 220 | } 221 | } 222 | 223 | normalize(obj) { 224 | /** Sort parsed user query elements of each type in alpha order **/ 225 | 226 | const query = obj.parsed.query 227 | 228 | // sort keywords 229 | query.keywords.sort() 230 | 231 | // sort tags 232 | query.tags.sort() 233 | 234 | // sort tags OR 235 | for(const tagsOrGroup of query.tagsOr){ 236 | tagsOrGroup.sort() 237 | } 238 | 239 | // sort tags NOT 240 | query.tagsNot.sort() 241 | 242 | // sort filters 243 | query.filters.sort((a,b) => a.field > b.field ? 1 : (b.field > a.field ? -1 : 0) ) 244 | } 245 | 246 | generateQuery(obj) { 247 | /** Generate clean, normalized query that has parts in right order **/ 248 | 249 | const query = obj.parsed.query 250 | 251 | // add keywords and tags 252 | const clean = [].concat(query.keywords, query.tags) 253 | 254 | // tags OR 255 | for(const tagsOr of query.tagsOr) 256 | clean.push(tagsOr.join('|')) 257 | 258 | // tags NOT 259 | for(const tagNot of query.tagsNot) 260 | clean.push('!' + tagNot) 261 | 262 | // filter 263 | for(const filter of query.filters){ 264 | if(Array.isArray(filter.value)) 265 | // multivalue or range filter, between 266 | if(filter.operator == '-') 267 | // range 268 | clean.push(`${filter.field}:${filter.value[0]}-${filter.value[1]}`) 269 | else 270 | // multivalue 271 | clean.push(`${filter.field}${filter.operator}${filter.value.join(',')}`) 272 | else 273 | // normal filter eq, gt, lt 274 | clean.push(filter.field + filter.operator + filter.value) 275 | } 276 | 277 | // sort 278 | let sorting = [] 279 | for(const sort of query.sort) { 280 | if(sort.order == 'random'){ 281 | // random sort cancels any other 282 | sorting = ['random'] 283 | break; 284 | } else { 285 | sorting.push(sort.field + ':' + sort.order) 286 | } 287 | } 288 | 289 | // done 290 | obj.query = [].concat(clean, sorting).join(' ') 291 | } 292 | 293 | generateSQL(obj, opts={}) { 294 | /** Generate SELECT and COUNT sql queries **/ 295 | 296 | const where = [] 297 | 298 | // add hard scope 299 | if(this.scope) 300 | where.push(this.scope) 301 | 302 | // add request scope 303 | if(opts.scope) 304 | where.push(opts.scope) 305 | 306 | // TAGS 307 | // - include all from each source 308 | 309 | for(const source of ['query', 'keywords', 'default']) { 310 | 311 | for(const tagAnd of obj.parsed[source].tags) 312 | where.push(`${this.search} LIKE '%${tagAnd}%'`) 313 | 314 | for(const tagOrGroup of obj.parsed[source].tagsOr){ 315 | const parts = [] 316 | for(const tagOr of tagOrGroup) 317 | parts.push(`${this.search} LIKE '%${tagOr}%'`) 318 | where.push(`(${parts.join(' OR ')})`) 319 | } 320 | 321 | for(const tagNot of obj.parsed[source].tagsNot) 322 | where.push(`${this.search} NOT LIKE '%${tagNot}%'`) 323 | } 324 | 325 | // FILTER 326 | // - include user query and keywords 327 | // - add default if not overriden by user query 328 | 329 | // track applied filters, used to determine if default filter on that field should be included 330 | const activeFilters = {} 331 | 332 | for(const source of ['query', 'keywords', 'default']){ 333 | 334 | for(const filter of obj.parsed[source].filters){ 335 | 336 | // use real field name, translate alias if it exists 337 | const realName = this.aliases[filter.field] || filter.field 338 | 339 | // skip default if already filtered on that field 340 | if(source == 'default' && activeFilters[realName]) 341 | continue; 342 | 343 | activeFilters[realName] = true 344 | 345 | where.push(this.processFilter(realName, filter)) 346 | } 347 | } 348 | 349 | // SORT 350 | // - only one source, order of precedence: query => keyword => default 351 | 352 | let sorting = [] 353 | sortLoop: // label for breaking from nested loop 354 | for(const source of ['query', 'keywords', 'default']){ 355 | 356 | if(!obj.parsed[source].sort.length) 357 | continue; 358 | 359 | for(const sort of obj.parsed[source].sort){ 360 | 361 | if(sort.order == 'random'){ 362 | sorting = ['RANDOM()'] 363 | // random cancels all other sort methods 364 | break sortLoop; 365 | } 366 | else 367 | // add elem to order clause, mind the alias 368 | sorting.push((this.aliases[sort.field] || sort.field) + ' ' + sort.order.toUpperCase()) 369 | } 370 | 371 | // only one source of sort is allowed 372 | // if we are here, that means we've got something, and we bolt 373 | break; 374 | } 375 | 376 | const sort = sorting.length ? 'ORDER BY ' + sorting.join(', ') : '' 377 | 378 | // LIMIT & OFFSET 379 | 380 | obj.offset = (obj.page - 1) * obj.limit 381 | const offset = `LIMIT ${obj.limit} OFFSET ${obj.offset}` 382 | 383 | // BUILD QUERY 384 | 385 | const select = this.select.join(', ') 386 | const count = this.count.join(', ') 387 | const whereStr = where.length ? 'WHERE ' + where.join(' AND ') : '' 388 | 389 | obj.sql.select = `SELECT ${select} FROM ${this.table} ${whereStr} ${sort} ${offset}` 390 | obj.sql.count = `SELECT ${count} FROM ${this.table} ${whereStr}` 391 | 392 | if(this.debug) 393 | obj.where = where 394 | } 395 | 396 | operators = { 397 | ':':'=', '<':'<', '>':'>', 398 | '!':'!=', ':<':'<=', ':>':'>=', 399 | } 400 | 401 | processFilter(fieldName, filter) { 402 | 403 | // get original or processed value, if processor is available 404 | const value = this.processors[fieldName] ? this.processors[fieldName](filter.value) : filter.value 405 | 406 | if(Array.isArray(value)) { 407 | // multivalue or range filter 408 | if(filter.operator == '-') 409 | return `${fieldName} BETWEEN ${value[0]} AND ${value[1]}` 410 | else 411 | return `${fieldName} ${filter.operator == ':' ? 'IN' : 'NOT IN'} (${value.map(val => isNaN(val) ? `'${val}'` : val).join(',')})` 412 | 413 | } else { 414 | 415 | // null value 416 | if(value == 'null') 417 | return fieldName + ' ISNULL' 418 | 419 | // normal filter 420 | return `${fieldName} ${this.operators[filter.operator]} ${isNaN(value) ? `'${value}'` : value}` 421 | } 422 | } 423 | } 424 | 425 | module.exports = LiQuery 426 | --------------------------------------------------------------------------------