1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
<?php
/*
Question2Answer by Gideon Greenspan and contributors
http://www.question2answer.org/
Description: Database-level access to user points and statistics
This program is free software; you can redistribute it and/or
modify it under the terms of the GNU General Public License
as published by the Free Software Foundation; either version 2
of the License, or (at your option) any later version.
This program is distributed in the hope that it will be useful,
but WITHOUT ANY WARRANTY; without even the implied warranty of
MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
GNU General Public License for more details.
More about this license: http://www.question2answer.org/license.php
*/
if (!defined('QA_VERSION')) { // don't allow this page to be requested directly from browser
header('Location: ../../');
exit;
}
/**
* Returns an array of option names required to perform calculations in userpoints table
*/
function qa_db_points_option_names()
{
if (qa_to_override(__FUNCTION__)) { $args=func_get_args(); return qa_call_override(__FUNCTION__, $args); }
return array(
'points_post_q', 'points_select_a', 'points_per_q_voted_up', 'points_per_q_voted_down', 'points_q_voted_max_gain', 'points_q_voted_max_loss',
'points_post_a', 'points_a_selected', 'points_per_a_voted_up', 'points_per_a_voted_down', 'points_a_voted_max_gain', 'points_a_voted_max_loss',
'points_per_c_voted_up', 'points_per_c_voted_down', 'points_c_voted_max_gain', 'points_c_voted_max_loss',
'points_vote_up_q', 'points_vote_down_q', 'points_vote_up_a', 'points_vote_down_a',
'points_multiple', 'points_base',
);
}
/**
* Returns an array containing all the calculation formulae for the userpoints table. Each element of this
* array is for one column - the key contains the column name, and the value is a further array of two elements.
* The element 'formula' contains the SQL fragment that calculates the columns value for one or more users,
* where the ~ symbol within the fragment is substituted for a constraint on which users we are interested in.
* The element 'multiple' specifies what to multiply each column by to create the final sum in the points column.
*/
function qa_db_points_calculations()
{
if (qa_to_override(__FUNCTION__)) { $args=func_get_args(); return qa_call_override(__FUNCTION__, $args); }
require_once QA_INCLUDE_DIR . 'app/options.php';
$options = qa_get_options(qa_db_points_option_names());
return array(
'qposts' => array(
'multiple' => $options['points_multiple'] * $options['points_post_q'],
'formula' => "COUNT(*) AS qposts FROM ^posts AS userid_src WHERE userid~ AND type='Q'",
),
'aposts' => array(
'multiple' => $options['points_multiple'] * $options['points_post_a'],
'formula' => "COUNT(*) AS aposts FROM ^posts AS userid_src WHERE userid~ AND type='A'",
),
'cposts' => array(
'multiple' => 0,
'formula' => "COUNT(*) AS cposts FROM ^posts AS userid_src WHERE userid~ AND type='C'",
),
'aselects' => array(
'multiple' => $options['points_multiple'] * $options['points_select_a'],
'formula' => "COUNT(*) AS aselects FROM ^posts AS userid_src WHERE userid~ AND type='Q' AND selchildid IS NOT NULL",
),
'aselecteds' => array(
'multiple' => $options['points_multiple'] * $options['points_a_selected'],
'formula' => "COUNT(*) AS aselecteds FROM ^posts AS userid_src JOIN ^posts AS questions ON questions.selchildid=userid_src.postid WHERE userid_src.userid~ AND userid_src.type='A' AND NOT (questions.userid<=>userid_src.userid)",
),
'qupvotes' => array(
'multiple' => $options['points_multiple'] * $options['points_vote_up_q'],
'formula' => "COUNT(*) AS qupvotes FROM ^uservotes AS userid_src JOIN ^posts ON userid_src.postid=^posts.postid WHERE userid_src.userid~ AND LEFT(^posts.type, 1)='Q' AND userid_src.vote>0",
),
'qdownvotes' => array(
'multiple' => $options['points_multiple'] * $options['points_vote_down_q'],
'formula' => "COUNT(*) AS qdownvotes FROM ^uservotes AS userid_src JOIN ^posts ON userid_src.postid=^posts.postid WHERE userid_src.userid~ AND LEFT(^posts.type, 1)='Q' AND userid_src.vote<0",
),
'aupvotes' => array(
'multiple' => $options['points_multiple'] * $options['points_vote_up_a'],
'formula' => "COUNT(*) AS aupvotes FROM ^uservotes AS userid_src JOIN ^posts ON userid_src.postid=^posts.postid WHERE userid_src.userid~ AND LEFT(^posts.type, 1)='A' AND userid_src.vote>0",
),
'adownvotes' => array(
'multiple' => $options['points_multiple'] * $options['points_vote_down_a'],
'formula' => "COUNT(*) AS adownvotes FROM ^uservotes AS userid_src JOIN ^posts ON userid_src.postid=^posts.postid WHERE userid_src.userid~ AND LEFT(^posts.type, 1)='A' AND userid_src.vote<0",
),
'cupvotes' => array(
'multiple' => 0,
'formula' => "COUNT(*) AS cupvotes FROM ^uservotes AS userid_src JOIN ^posts ON userid_src.postid=^posts.postid WHERE userid_src.userid~ AND LEFT(^posts.type, 1)='C' AND userid_src.vote>0",
),
'cdownvotes' => array(
'multiple' => 0,
'formula' => "COUNT(*) AS cdownvotes FROM ^uservotes AS userid_src JOIN ^posts ON userid_src.postid=^posts.postid WHERE userid_src.userid~ AND LEFT(^posts.type, 1)='C' AND userid_src.vote<0",
),
'qvoteds' => array(
'multiple' => $options['points_multiple'],
'formula' => "COALESCE(SUM(" .
"LEAST(" . ((int)$options['points_per_q_voted_up']) . "*upvotes," . ((int)$options['points_q_voted_max_gain']) . ")" .
"-" .
"LEAST(" . ((int)$options['points_per_q_voted_down']) . "*downvotes," . ((int)$options['points_q_voted_max_loss']) . ")" .
"), 0) AS qvoteds FROM ^posts AS userid_src WHERE LEFT(type, 1)='Q' AND userid~",
),
'avoteds' => array(
'multiple' => $options['points_multiple'],
'formula' => "COALESCE(SUM(" .
"LEAST(" . ((int)$options['points_per_a_voted_up']) . "*upvotes," . ((int)$options['points_a_voted_max_gain']) . ")" .
"-" .
"LEAST(" . ((int)$options['points_per_a_voted_down']) . "*downvotes," . ((int)$options['points_a_voted_max_loss']) . ")" .
"), 0) AS avoteds FROM ^posts AS userid_src WHERE LEFT(type, 1)='A' AND userid~",
),
'cvoteds' => array(
'multiple' => $options['points_multiple'],
'formula' => "COALESCE(SUM(" .
"LEAST(" . ((int)$options['points_per_c_voted_up']) . "*upvotes," . ((int)$options['points_c_voted_max_gain']) . ")" .
"-" .
"LEAST(" . ((int)$options['points_per_c_voted_down']) . "*downvotes," . ((int)$options['points_c_voted_max_loss']) . ")" .
"), 0) AS cvoteds FROM ^posts AS userid_src WHERE LEFT(type, 1)='C' AND userid~",
),
'upvoteds' => array(
'multiple' => 0,
'formula' => "COALESCE(SUM(upvotes), 0) AS upvoteds FROM ^posts AS userid_src WHERE userid~",
),
'downvoteds' => array(
'multiple' => 0,
'formula' => "COALESCE(SUM(downvotes), 0) AS downvoteds FROM ^posts AS userid_src WHERE userid~",
),
);
}
/**
* Update the userpoints table in the database for $userid and $columns, plus the summary points column.
* Set $columns to true for all, empty for none, an array for several, or a single value for one.
* This dynamically builds some fairly crazy looking SQL, but it works, and saves repeat calculations.
* @param $userid
* @param $columns
* @return mixed
*/
function qa_db_points_update_ifuser($userid, $columns)
{
if (qa_to_override(__FUNCTION__)) { $args=func_get_args(); return qa_call_override(__FUNCTION__, $args); }
if (qa_should_update_counts() && isset($userid)) {
require_once QA_INCLUDE_DIR . 'app/options.php';
require_once QA_INCLUDE_DIR . 'app/cookies.php';
$calculations = qa_db_points_calculations();
if ($columns === true) {
$keycolumns = $calculations;
} elseif (empty($columns)) {
$keycolumns = array();
} elseif (is_array($columns)) {
$keycolumns = array_flip($columns);
} else {
$keycolumns = array($columns => true);
}
$insertfields = 'userid, ';
$insertvalues = '$, ';
$insertpoints = (int)qa_opt('points_base');
$updates = '';
$updatepoints = $insertpoints;
foreach ($calculations as $field => $calculation) {
$multiple = (int)$calculation['multiple'];
if (isset($keycolumns[$field])) {
$insertfields .= $field . ', ';
$insertvalues .= '@_' . $field . ':=(SELECT ' . $calculation['formula'] . '), ';
$updates .= $field . '=@_' . $field . ', ';
$insertpoints .= '+(' . (int)$multiple . '*@_' . $field . ')';
}
$updatepoints .= '+(' . $multiple . '*' . (isset($keycolumns[$field]) ? '@_' : '') . $field . ')';
}
$query = 'INSERT INTO ^userpoints (' . $insertfields . 'points) VALUES (' . $insertvalues . $insertpoints . ') ' .
'ON DUPLICATE KEY UPDATE ' . $updates . 'points=' . $updatepoints . '+bonus';
// build like this so that a #, $ or ^ character in the $userid (if external integration) isn't substituted
qa_db_query_raw(str_replace('~', "='" . qa_db_escape_string($userid) . "'", qa_db_apply_sub($query, array($userid))));
if (qa_db_insert_on_duplicate_inserted()) {
qa_db_userpointscount_update();
}
}
}
/**
* Set the number of explicit bonus points for $userid to $bonus
* @param $userid
* @param $bonus
*/
function qa_db_points_set_bonus($userid, $bonus)
{
qa_db_query_sub(
"INSERT INTO ^userpoints (userid, bonus) VALUES ($, #) ON DUPLICATE KEY UPDATE bonus=#",
$userid, $bonus, $bonus
);
}
/**
* Update the cached count in the database of the number of rows in the userpoints table
*/
function qa_db_userpointscount_update()
{
if (qa_should_update_counts()) {
qa_db_query_sub(
"INSERT INTO ^options (title, content) " .
"SELECT 'cache_userpointscount', COUNT(*) FROM ^userpoints " .
"ON DUPLICATE KEY UPDATE content = VALUES(content)"
);
}
}