Magellan Linux

Contents of /alx-src/branches/alx-web-070/scripts/sql-schema/mcore-sql-schema.sh

Parent Directory Parent Directory | Revision Log Revision Log


Revision 8505 - (show annotations) (download) (as text)
Fri Feb 5 15:16:07 2016 UTC (8 years, 2 months ago) by niro
File MIME type: application/x-sh
File size: 10676 byte(s)
-removed obsolete debug message
1 #!/bin/bash
2
3 # include everything from include
4 for inc in $(find ./include -type f -name \*.sh)
5 do
6 source "${inc}"
7 done
8
9 die()
10 {
11 echo "ERROR: $@"
12 exit 1
13 }
14
15 mysql_command()
16 {
17 local sql_user
18 local sql_pass
19 local sql_host
20 local sql_db
21 local sql_command
22
23 sql_user=$1
24 sql_pass=$2
25 sql_host=$3
26 sql_db=$4
27 sql_command=$5
28
29 #fallback (sql_opts not, they are optional )
30 if [ -z "${sql_user}" \
31 -o -z "${sql_pass}" \
32 -o -z "${sql_host}" \
33 -o -z "${sql_db}" \
34 -o -z "${sql_command}" ]
35 then
36 echo
37 echo "Usage:"
38 echo -e " mysql_command user pass host db \"sql-command\""
39 echo
40 return 1
41 fi
42
43 mysql \
44 --user="${sql_user}" \
45 --password="${sql_pass}" \
46 --host="${sql_host}" \
47 --database="${sql_db}" \
48 --batch \
49 --skip-column-names \
50 --execute="${sql_command}" \
51 || return 1
52
53 return 0
54 }
55
56 mysqldo()
57 {
58 mysql_command \
59 "${MCORE_SQL_USER}" \
60 "${MCORE_SQL_PASS}" \
61 "${MCORE_SQL_HOST}" \
62 "${MCORE_SQL_DB}" \
63 "$@" \
64 && return 0 || return 1
65 }
66
67 # creates a mysql table with help of a defined array TABLE_DEFINITION:
68 # array values are a struct like this:
69 # first array element is the table name, everything else are column descriptions
70 # TABLE_DEFINITION=(
71 # "table_name"
72 # "column1_name column1_argvs"
73 # "column2_name column2_argvs"
74 # "columnN_name columnN_argvs"
75 # )
76 sql_create_table()
77 {
78 local table
79 local count
80 local i
81 local line
82 local opts
83 local column
84 local autoincrement
85 local primary
86 local create
87
88 table="${TABLE_DEFINITION[0]}"
89 count="${#TABLE_DEFINITION[*]}"
90
91 for ((i=1; i<count; i++))
92 do
93 line=( ${TABLE_DEFINITION[${i}]} )
94 column="${line[0]}"
95 opts="${line[*]:1}"
96
97 case ${opts} in
98 *"PRIMARY KEY"*) opts="${opts//PRIMARY KEY}"; primary="${column}" ;;
99 *"primary key"*) opts="${opts//primary key}"; primary="${column}" ;;
100 esac
101
102 case ${opts} in
103 *AUTO_INCREMENT*) opts="${opts//AUTO_INCREMENT}"; autoincrement="${column} ${opts}" ;;
104 *auto_increment*) opts="${opts//auto_increment}"; autoincrement="${column} ${opts}" ;;
105 esac
106
107 if [[ -z ${create} ]]
108 then
109 create="${column} ${opts}"
110 else
111 create+=", ${column} ${opts}"
112 fi
113 done
114 mysqldo "CREATE TABLE ${MCORE_SQL_DB}.${table} ( ${create} );" || die "creating table '${table}'"
115
116 if [[ -n ${primary} ]]
117 then
118 mysqldo "ALTER TABLE ${MCORE_SQL_DB}.${table} ADD PRIMARY KEY (${primary});" || die "adding primary key to table '${table}'"
119 fi
120 if [[ -n ${autoincrement} ]]
121 then
122 mysqldo "ALTER TABLE ${MCORE_SQL_DB}.${table} MODIFY ${autoincrement} AUTO_INCREMENT;" || die "adding auto_increment to table '${table}'"
123 fi
124 }
125
126 # TABLE_DEFINITION=(
127 # "table_name"
128 # "column1_name after_column column1_argvs"
129 # "column2_name after_column column2_argvs"
130 # "columnN_name after_column columnN_argvs"
131 # )
132 sql_add_column()
133 {
134 local table
135 local count
136 local i
137 local line
138 local opts
139 local column
140 local autoincrement
141 local primary
142 local current_primary
143 local current_autoincrement
144 local current_opts
145
146 table="${TABLE_DEFINITION[0]}"
147 count="${#TABLE_DEFINITION[*]}"
148
149 for ((i=1; i<count; i++))
150 do
151 line=( ${TABLE_DEFINITION[${i}]} )
152 column="${line[0]}"
153 after="${line[1]}"
154 opts="${line[*]:2}"
155
156 case ${opts} in
157 *"PRIMARY KEY"*) opts="${opts//PRIMARY KEY}"; primary="${column}" ;;
158 *"primary key"*) opts="${opts//primary key}"; primary="${column}" ;;
159 esac
160
161 case ${opts} in
162 *AUTO_INCREMENT*) opts="${opts//AUTO_INCREMENT}"; autoincrement="${column} ${opts}" ;;
163 *auto_increment*) opts="${opts//auto_increment}"; autoincrement="${column} ${opts}" ;;
164 esac
165
166 mysqldo "ALTER TABLE ${MCORE_SQL_DB}.${table} ADD ${column} ${opts} AFTER ${after_column};" || die "add column '${table}'"
167 done
168
169 # delete an existing auto_increment first
170 if [[ -n ${autoincrement} ]]
171 then
172 i=( $(mysqldo 'SHOW COLUMNS FROM '${MCORE_SQL_DB}.${table}' WHERE `Extra`="auto_increment"') )
173 current_autoincrement="${i[0]}"
174 if [[ ${current_autoincrement} != ${column} ]] && [[ -n ${current_autoincrement} ]]
175 then
176 current_opts=( "${i[1]}" ) # type eg int(11)
177 # null or not
178 case "${i[2]}" in
179 NO|no) current_opts+=( "NOT NULL" ) ;;
180 YES|yes) current_opts+=( "DEFAULT ${i[4]}" ) ;; # should never match, but to be save
181 esac
182 mysqldo "ALTER TABLE ${MCORE_SQL_DB}.${table} CHANGE ${current_autoincrement} ${current_autoincrement} ${current_opts};" || die "removing auto_increment to table '${table}'"
183 fi
184 fi
185
186 if [[ -n ${primary} ]]
187 then
188 # only run this if the primary key is not already the same column
189 i=( $(mysqldo 'SHOW COLUMNS FROM '${MCORE_SQL_DB}.${table}' WHERE `Key`="PRI"') )
190 current_primary="${i[0]}"
191 if [[ -n ${current_primary} ]]
192 then
193 mysqldo "ALTER TABLE ${MCORE_SQL_DB}.${table} DROP PRIMARY KEY;" || die "adding primary key to table '${table}'"
194 fi
195 mysqldo "ALTER TABLE ${MCORE_SQL_DB}.${table} ADD PRIMARY KEY (${primary});" || die "adding primary key to table '${table}'"
196 fi
197 if [[ -n ${autoincrement} ]]
198 then
199 mysqldo "ALTER TABLE ${MCORE_SQL_DB}.${table} MODIFY ${autoincrement} AUTO_INCREMENT;" || die "adding auto_increment to table '${table}'"
200 fi
201 }
202
203 # TABLE_DEFINITION=(
204 # "table_name"
205 # "column1_name column1_argvs"
206 # "column2_name column2_argvs"
207 # "columnN_name columnN_argvs"
208 # )
209 sql_modify_column()
210 {
211 local table
212 local count
213 local i
214 local line
215 local opts
216 local column
217 local autoincrement
218 local primary
219 local current_primary
220 local current_autoincrement
221 local current_opts
222
223 table="${TABLE_DEFINITION[0]}"
224 count="${#TABLE_DEFINITION[*]}"
225
226 for ((i=1; i<count; i++))
227 do
228 line=( ${TABLE_DEFINITION[${i}]} )
229 column="${line[0]}"
230 opts="${line[*]:1}"
231
232 case ${opts} in
233 *"PRIMARY KEY"*) opts="${opts//PRIMARY KEY}"; primary="${column}" ;;
234 *"primary key"*) opts="${opts//primary key}"; primary="${column}" ;;
235 esac
236
237 case ${opts} in
238 *AUTO_INCREMENT*) opts="${opts//AUTO_INCREMENT}"; autoincrement="${column} ${opts}" ;;
239 *auto_increment*) opts="${opts//auto_increment}"; autoincrement="${column} ${opts}" ;;
240 esac
241
242 mysqldo "ALTER TABLE ${MCORE_SQL_DB}.${table} MODIFY ${column} ${opts};" || die "modify table '${table}'"
243 done
244
245 # delete an existing auto_increment first
246 if [[ -n ${autoincrement} ]]
247 then
248 i=( $(mysqldo 'SHOW COLUMNS FROM '${MCORE_SQL_DB}.${table}' WHERE `Extra`="auto_increment"') )
249 echo "DEBUG: i='${i[*]}'"
250 current_autoincrement="${i[0]}"
251 if [[ ${current_autoincrement} != ${column} ]] && [[ -n ${current_autoincrement} ]]
252 then
253 current_opts=( "${i[1]}" ) # type eg int(11)
254 # null or not
255 case "${i[2]}" in
256 NO|no) current_opts+=( "NOT NULL" ) ;;
257 YES|yes) current_opts+=( "DEFAULT ${i[4]}" ) ;; # should never match, but to be save
258 esac
259 mysqldo "ALTER TABLE ${MCORE_SQL_DB}.${table} CHANGE ${current_autoincrement} ${current_autoincrement} ${current_opts};" || die "removing auto_increment to table '${table}'"
260 fi
261 fi
262
263 if [[ -n ${primary} ]]
264 then
265 # only run this if the primary key is not already the same column
266 i=( $(mysqldo 'SHOW COLUMNS FROM '${MCORE_SQL_DB}.${table}' WHERE `Key`="PRI"') )
267 current_primary="${i[0]}"
268 if [[ -n ${current_primary} ]]
269 then
270 mysqldo "ALTER TABLE ${MCORE_SQL_DB}.${table} DROP PRIMARY KEY;" || die "adding primary key to table '${table}'"
271 fi
272 mysqldo "ALTER TABLE ${MCORE_SQL_DB}.${table} ADD PRIMARY KEY (${primary});" || die "adding primary key to table '${table}'"
273 fi
274 if [[ -n ${autoincrement} ]]
275 then
276 mysqldo "ALTER TABLE ${MCORE_SQL_DB}.${table} MODIFY ${autoincrement} AUTO_INCREMENT;" || die "adding auto_increment to table '${table}'"
277 fi
278 }
279
280 # VALUE_DEFINITION=(
281 # "table_name, value_column_name, bool_column_name, id_column_name"
282 # "value1, bool1"
283 # "value2, bool2"
284 # "valueN, boolN"
285 # )
286 sql_set_value()
287 {
288 local line
289 local meta
290 local table
291 local column_value
292 local column_bool
293 local column_id
294 local value
295 local bool
296 local count
297 local i
298 local id
299
300 count="${#VALUE_DEFINITION[*]}"
301 line="${VALUE_DEFINITION[0]}"
302 for i in ${line//,/ }
303 do
304 meta+=( "${i}" )
305 done
306
307 table="${meta[0]}"
308 column_value="${meta[1]}"
309 column_bool="${meta[2]}"
310 column_id="${meta[3]}"
311
312 for ((i=1; i<count; i++))
313 do
314 line="${VALUE_DEFINITION[${i}]}"
315 value="${line%%,*}"
316 bool="${line##*,}"
317 # remove any leading whitespaces
318 bool="${bool// }"
319
320 # now check if the value already exist in the database
321 id=$(mysqldo "SELECT ${column_id} FROM ${MCORE_SQL_DB}.${table} WHERE ${column_value}='${value}';")
322 if [[ -n ${id} ]]
323 then
324 # update value in database
325 mysqldo "UPDATE ${MCORE_SQL_DB}.${table} SET ${column_value}='${value}', ${column_bool}='${bool}' WHERE ${column_id}='${id}';" || die "update value in table ${table}"
326 else
327 # insert into the database
328 mysqldo "INSERT INTO ${MCORE_SQL_DB}.${table} (${column_value}, ${column_bool}) VALUES ( '${value}', '${bool}' );" || die "insert value into table ${table}"
329 fi
330 done
331 }
332
333 create_database()
334 {
335 create_database_schema
336
337 # update database schema version
338 mysqldo "INSERT INTO ${MCORE_SQL_DB}.meta_schema(version) VALUES ('${MCORE_SQL_DB_SCHEMA_VERSION}') ON DUPLICATE KEY UPDATE version='${MCORE_SQL_DB_SCHEMA_VERSION}';" || die "updating schema version"
339 }
340
341 update_database()
342 {
343 local current_sql_db_schema_version
344 local i
345
346 current_sql_db_schema_version=$(mysqldo "SELECT MAX(version) from meta_schema;")
347
348 if [[ ${current_sql_db_schema_version} = ${MCORE_SQL_DB_SCHEMA_VERSION} ]]
349 then
350 echo "Database schema is already up to date"
351 return 0
352 fi
353
354 # run every update_to_database_version_X script which exist up to version MCORE_SQL_DB_SCHEMA_VERSION
355 for i in $(seq $((${current_sql_db_schema_version}+1)) ${MCORE_SQL_DB_SCHEMA_VERSION})
356 do
357 if [[ -n $(typeset -f update_to_database_schema_version_${i}) ]]
358 then
359 echo "Running update_to_database_schema_version_${i}()"
360 update_to_database_schema_version_${i} || die
361 fi
362 done
363
364 # update database schema version
365 mysqldo "INSERT INTO ${MCORE_SQL_DB}.meta_schema(version) VALUES ('${MCORE_SQL_DB_SCHEMA_VERSION}') ON DUPLICATE KEY UPDATE version='${MCORE_SQL_DB_SCHEMA_VERSION}';" || die "updating schema version"
366 }
367
368 fill_database()
369 {
370 local current_sql_db_values_version
371 local i
372
373 current_sql_db_values_version=$(mysqldo "SELECT MAX(version) from meta_values;")
374
375 if [[ ${current_sql_db_values_version} = ${MCORE_SQL_DB_VALUES_VERSION} ]]
376 then
377 echo "Database values are already up to date"
378 return 0
379 fi
380
381 create_database_values
382 # update database values version
383 mysqldo "INSERT INTO ${MCORE_SQL_DB}.meta_values(version) VALUES ('${MCORE_SQL_DB_VALUES_VERSION}') ON DUPLICATE KEY UPDATE version='${MCORE_SQL_DB_VALUES_VERSION}';" || die "updating values version"
384 }
385
386 case $1 in
387 create)
388 create_database
389 fill_database
390 ;;
391
392 update)
393 update_database
394 fill_database
395 ;;
396 esac