ser_mysql.sh 12 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494
  1. #!/bin/sh
  2. #
  3. # $Id$
  4. #
  5. # Script for adding and dropping ser MySql tables
  6. #
  7. # TO-DO: update_structures command for migriting to new
  8. # table definitons
  9. # USAGE: call the command without any parameters for info
  10. #
  11. #################################################################
  12. # config vars
  13. #################################################################
  14. DBNAME=ser
  15. DBHOST=localhost
  16. USERNAME=ser
  17. DEFAULT_PW=heslo
  18. ROUSER=serro
  19. RO_PW=47serro11
  20. CMD="mysql -h $DBHOST -p -u "
  21. BACKUP_CMD="mysqldump -h $DBHOST -p -c -t -u "
  22. TABLE_TYPE="TYPE=MyISAM"
  23. SQL_USER="root"
  24. #################################################################
  25. usage() {
  26. COMMAND=`basename $0`
  27. cat <<EOF
  28. usage: $COMMAND create
  29. $COMMAND drop (!!entirely deletes tables)
  30. $COMMAND reinit (!!entirely deletes and than re-creates tables
  31. $COMMAND backup (dumps current database to stdout)
  32. $COMMAND restore <file> (restores tables from a file)
  33. $COMMAND copy <new_db> (creates a new db from an existing one)
  34. if you want to manipulate database as other MySql user than
  35. root, want to change database name from default value "$DBNAME",
  36. or want to use other values for users and password, edit the
  37. "config vars" section of the command $COMMAND
  38. EOF
  39. } #usage
  40. ser_backup() # pars: <database name> <sql_user>
  41. {
  42. if [ $# -ne 2 ] ; then
  43. echo "ser_drop function takes two params"
  44. exit 1
  45. fi
  46. $BACKUP_CMD $2 $1
  47. }
  48. ser_restore() #pars: <database name> <sql_user> <filename>
  49. {
  50. if [ $# -ne 3 ] ; then
  51. echo "ser_drop function takes two params"
  52. exit 1
  53. fi
  54. $CMD $2 $1 < $3
  55. }
  56. ser_drop() # pars: <database name> <sql_user>
  57. {
  58. if [ $# -ne 2 ] ; then
  59. echo "ser_drop function takes two params"
  60. exit 1
  61. fi
  62. $CMD $2 << EOF
  63. drop database $1;
  64. EOF
  65. } #ser_drop
  66. ser_create () # pars: <database name> <sql_user>
  67. {
  68. #test
  69. #cat > /tmp/sss <<EOF
  70. if [ $# -ne 2 ] ; then
  71. echo "ser_create function takes two params"
  72. exit 1
  73. fi
  74. echo "creating database $1 ..."
  75. $CMD $2 <<EOF
  76. create database $1;
  77. use $1;
  78. # Users: ser is the regular user, serro only for reading
  79. GRANT ALL PRIVILEGES ON $1.* TO $USERNAME IDENTIFIED BY '$DEFAULT_PW';
  80. GRANT ALL PRIVILEGES ON $1.* TO ${USERNAME}@$DBHOST IDENTIFIED BY '$DEFAULT_PW';
  81. GRANT SELECT ON $1.* TO $ROUSER IDENTIFIED BY '$RO_PW';
  82. GRANT SELECT ON $1.* TO ${ROUSER}@$DBHOST IDENTIFIED BY '$RO_PW';
  83. #
  84. # Table structure versions
  85. #
  86. CREATE TABLE version (
  87. table_name varchar(64) NOT NULL,
  88. version smallint(5) DEFAULT '0' NOT NULL
  89. ) $TABLE_TYPE;
  90. #
  91. # Dumping data for table 'version'
  92. #
  93. INSERT INTO version VALUES ( 'subscriber', '1');
  94. INSERT INTO version VALUES ( 'reserved', '1');
  95. INSERT INTO version VALUES ( 'phonebook', '1');
  96. INSERT INTO version VALUES ( 'pending', '1');
  97. INSERT INTO version VALUES ( 'missed_calls', '1');
  98. INSERT INTO version VALUES ( 'location', '2');
  99. INSERT INTO version VALUES ( 'grp', '2');
  100. INSERT INTO version VALUES ( 'event', '1');
  101. INSERT INTO version VALUES ( 'aliases', '2');
  102. INSERT INTO version VALUES ( 'active_sessions', '1');
  103. INSERT INTO version VALUES ( 'acc', '1');
  104. INSERT INTO version VALUES ( 'config', '1');
  105. INSERT INTO version VALUES ( 'silo', '1');
  106. INSERT INTO version VALUES ( 'realm', '1');
  107. INSERT INTO version VALUES ( 'uri', '1');
  108. #
  109. # Table structure for table 'acc' -- accounted calls
  110. #
  111. CREATE TABLE acc (
  112. sip_from varchar(128) NOT NULL default '',
  113. sip_to varchar(128) NOT NULL default '',
  114. sip_status varchar(128) NOT NULL default '',
  115. sip_method varchar(16) NOT NULL default '',
  116. i_uri varchar(128) NOT NULL default '',
  117. o_uri varchar(128) NOT NULL default '',
  118. sip_callid varchar(128) NOT NULL default '',
  119. user varchar(64) NOT NULL default '',
  120. time datetime NOT NULL default '0000-00-00 00:00:00',
  121. timestamp timestamp(14) NOT NULL
  122. ) $TABLE_TYPE;
  123. #
  124. # Table structure for table 'active_sessions' -- web stuff
  125. #
  126. CREATE TABLE active_sessions (
  127. sid varchar(32) NOT NULL default '',
  128. name varchar(32) NOT NULL default '',
  129. val text,
  130. changed varchar(14) NOT NULL default '',
  131. PRIMARY KEY (name,sid),
  132. KEY changed (changed)
  133. ) $TABLE_TYPE;
  134. #
  135. # Table structure for table 'aliases' -- location-like table
  136. #
  137. CREATE TABLE aliases (
  138. user varchar(50) NOT NULL default '',
  139. domain varchar(100) NOT NULL default '',
  140. contact varchar(255) NOT NULL default '',
  141. expires datetime default NULL,
  142. q float(10,2) default NULL,
  143. callid varchar(255) default NULL,
  144. cseq int(11) default NULL,
  145. last_modified timestamp(14) NOT NULL,
  146. KEY user (user, domain, contact)
  147. ) $TABLE_TYPE;
  148. #
  149. # Table structure for table 'event' -- track of predefined
  150. # events to which a user subscribed
  151. #
  152. CREATE TABLE event (
  153. id int(10) unsigned NOT NULL auto_increment,
  154. user varchar(50) NOT NULL default '',
  155. uri varchar(255) NOT NULL default '',
  156. description varchar(255) NOT NULL default '',
  157. PRIMARY KEY (id),
  158. UNIQUE KEY id (id)
  159. ) $TABLE_TYPE;
  160. #
  161. # Table structure for table 'grp' -- group membership
  162. # table; used primarily for ACLs
  163. #
  164. CREATE TABLE grp (
  165. user varchar(50) NOT NULL default '',
  166. domain varchar(100) NOT NULL default '',
  167. grp varchar(50) NOT NULL default '',
  168. last_modified datetime NOT NULL default '0000-00-00 00:00:00'
  169. ) $TABLE_TYPE;
  170. #
  171. # Table structure for table 'location' -- that is persistent UsrLoc
  172. #
  173. CREATE TABLE location (
  174. user varchar(50) NOT NULL default '',
  175. domain varchar(100) NOT NULL default '',
  176. contact varchar(255) NOT NULL default '',
  177. expires datetime default NULL,
  178. q float(10,2) default NULL,
  179. callid varchar(255) default NULL,
  180. cseq int(11) default NULL,
  181. last_modified timestamp(14) NOT NULL,
  182. KEY user (user, domain, contact)
  183. ) $TABLE_TYPE;
  184. #
  185. # Table structure for table 'missed_calls' -- acc-like table
  186. # for keeping track of missed calls
  187. #
  188. CREATE TABLE missed_calls (
  189. sip_from varchar(128) NOT NULL default '',
  190. sip_to varchar(128) NOT NULL default '',
  191. sip_status varchar(128) NOT NULL default '',
  192. sip_method varchar(16) NOT NULL default '',
  193. i_uri varchar(128) NOT NULL default '',
  194. o_uri varchar(128) NOT NULL default '',
  195. sip_callid varchar(128) NOT NULL default '',
  196. user varchar(64) NOT NULL default '',
  197. time datetime NOT NULL default '0000-00-00 00:00:00',
  198. timestamp timestamp(14) NOT NULL
  199. ) $TABLE_TYPE;
  200. #
  201. # Table structure for table 'pending' -- unconfirmed subscribtion
  202. # requests
  203. #
  204. CREATE TABLE pending (
  205. phplib_id varchar(32) NOT NULL default '',
  206. USER_ID varchar(100) NOT NULL default '',
  207. PASSWORD varchar(25) NOT NULL default '',
  208. FIRST_NAME varchar(25) NOT NULL default '',
  209. LAST_NAME varchar(45) NOT NULL default '',
  210. PHONE varchar(15) NOT NULL default '',
  211. EMAIL_ADDRESS varchar(50) NOT NULL default '',
  212. DATETIME_CREATED datetime NOT NULL default '0000-00-00 00:00:00',
  213. DATETIME_MODIFIED datetime NOT NULL default '0000-00-00 00:00:00',
  214. confirmation varchar(64) NOT NULL default '',
  215. flag char(1) NOT NULL default 'o',
  216. SendNotification varchar(50) NOT NULL default '',
  217. Greeting varchar(50) NOT NULL default '',
  218. HA1 varchar(128) NOT NULL default '',
  219. REALM varchar(128) NOT NULL default '',
  220. ha1b varchar(128) NOT NULL default '',
  221. perms varchar(32) default NULL,
  222. allow_find char(1) NOT NULL default '0',
  223. timezone varchar(128) default NULL,
  224. UNIQUE KEY USER_ID (USER_ID),
  225. KEY USER_ID_2 (USER_ID),
  226. UNIQUE KEY phplib_id (phplib_id)
  227. ) $TABLE_TYPE;
  228. #
  229. # Table structure for table 'phonebook' -- user's phonebook
  230. #
  231. CREATE TABLE phonebook (
  232. id int(10) unsigned NOT NULL auto_increment,
  233. user varchar(50) NOT NULL default '',
  234. fname varchar(32) NOT NULL default '',
  235. lname varchar(32) NOT NULL default '',
  236. sip_uri varchar(128) NOT NULL default '',
  237. PRIMARY KEY (id),
  238. UNIQUE KEY id (id)
  239. ) $TABLE_TYPE;
  240. #
  241. # Table structure for table 'reserved' -- reserved username
  242. # which should be never allowed for subscription
  243. #
  244. CREATE TABLE reserved (
  245. user_id char(100) NOT NULL default '',
  246. UNIQUE KEY user_id (user_id)
  247. ) $TABLE_TYPE;
  248. #
  249. # Table structure for table 'subscriber' -- user database
  250. # (note: realm is only informational -- it is defined
  251. # in ser scripts)
  252. #
  253. CREATE TABLE subscriber (
  254. phplib_id varchar(32) NOT NULL default '',
  255. USER_ID varchar(100) NOT NULL default '',
  256. PASSWORD varchar(25) NOT NULL default '',
  257. FIRST_NAME varchar(25) NOT NULL default '',
  258. LAST_NAME varchar(45) NOT NULL default '',
  259. PHONE varchar(15) NOT NULL default '',
  260. EMAIL_ADDRESS varchar(50) NOT NULL default '',
  261. DATETIME_CREATED datetime NOT NULL default '0000-00-00 00:00:00',
  262. DATETIME_MODIFIED datetime NOT NULL default '0000-00-00 00:00:00',
  263. confirmation varchar(64) NOT NULL default '',
  264. flag char(1) NOT NULL default 'o',
  265. SendNotification varchar(50) NOT NULL default '',
  266. Greeting varchar(50) NOT NULL default '',
  267. HA1 varchar(128) NOT NULL default '',
  268. REALM varchar(128) NOT NULL default '',
  269. ha1b varchar(128) NOT NULL default '',
  270. perms varchar(32) default NULL,
  271. allow_find char(1) NOT NULL default '0',
  272. timezone varchar(128) default NULL,
  273. UNIQUE KEY phplib_id (phplib_id),
  274. UNIQUE KEY USER_ID (USER_ID),
  275. KEY USER_ID_2 (USER_ID)
  276. ) $TABLE_TYPE;
  277. # hook-table for all posssible future config values
  278. # (currently unused)
  279. CREATE TABLE config (
  280. attribute varchar(32) NOT NULL,
  281. value varchar(128) NOT NULL,
  282. user varchar(100) NOT NULL default '',
  283. modified timestamp(14)
  284. ) $TABLE_TYPE;
  285. # "instant" message silo
  286. CREATE TABLE silo(
  287. mid INTEGER NOT NULL AUTO_INCREMENT PRIMARY KEY,
  288. iuri VARCHAR(128),
  289. ouri VARCHAR(128) NOT NULL,
  290. to_h VARCHAR(128),
  291. from_h VARCHAR(128),
  292. inc_time INTEGER NOT NULL DEFAULT 0,
  293. exp_time INTEGER NOT NULL,
  294. ctype VARCHAR(32) NOT NULL DEFAULT "text/plain",
  295. body BLOB NOT NULL
  296. ) $TABLE_TYPE ;
  297. #
  298. # Table structure for table 'domain' -- domains proxy is responsible for
  299. #
  300. CREATE TABLE domain (
  301. domain varchar(50) NOT NULL default '',
  302. last_modified datetime NOT NULL default '0000-00-00 00:00:00',
  303. PRIMARY KEY (domain)
  304. ) $TABLE_TYPE;
  305. #
  306. # Table structure for table 'uri' -- uri user parts users are allowed to use
  307. #
  308. CREATE TABLE uri (
  309. user varchar(50) NOT NULL default '',
  310. domain varchar(50) NOT NULL default '',
  311. uri_user varchar(50) NOT NULL default '',
  312. last_modified datetime NOT NULL default '0000-00-00 00:00:00',
  313. PRIMARY KEY (user, domain, uri_user)
  314. ) $TABLE_TYPE;
  315. # add an admin user "admin" with password==heslo,
  316. # so that one can try it out on quick start
  317. INSERT INTO subscriber (USER_ID, PASSWORD, FIRST_NAME, LAST_NAME, PHONE,
  318. EMAIL_ADDRESS, DATETIME_CREATED, DATETIME_MODIFIED, confirmation,
  319. flag, SendNotification, Greeting, HA1, REALM, ha1b, phplib_id, perms )
  320. VALUES ( 'admin', 'heslo', 'Initial', 'Admin', '123',
  321. 'root@localhost', '2002-09-04 19:37:45', '0000-00-00 00:00:00',
  322. '57DaSIPuCm52UNe54LF545750cfdL48OMZfroM53', 'o', '', '',
  323. '0239482f19d262f3953186a725a6f53b', 'iptel.org',
  324. 'a84e8abaa7e83d1b45c75ab15b90c320', '65e397cda0aa8e3202ea22cbd350e4e9', 'admin' );
  325. EOF
  326. } # ser_create
  327. case $1 in
  328. copy)
  329. shift
  330. if [ $# -ne 1 ]; then
  331. usage
  332. exit 1
  333. fi
  334. tmp_file=/tmp/ser_mysql.$$
  335. ser_backup $DBNAME $SQL_USER > $tmp_file
  336. ret=$?
  337. if [ "$ret" -ne 0 ]; then
  338. rm $tmp_file
  339. exit $ret
  340. fi
  341. ser_create $1 $SQL_USER
  342. ret=$?
  343. if [ "$ret" -ne 0 ]; then
  344. rm $tmp_file
  345. exit $ret
  346. fi
  347. ser_restore $1 $SQL_USER $tmp_file
  348. ret=$?
  349. rm $tmp_file
  350. exit $ret
  351. ;;
  352. backup)
  353. ser_backup $DBNAME $SQL_USER
  354. exit $?
  355. ;;
  356. restore)
  357. shift
  358. if [ $# -ne 1 ]; then
  359. usage
  360. exit 1
  361. fi
  362. ser_restore $DBNAME $SQL_USER $1
  363. exit $?
  364. ;;
  365. create)
  366. shift
  367. if [ $# -eq 1 ] ; then
  368. DBNAME="$1"
  369. fi
  370. ser_create $DBNAME $SQL_USER
  371. exit $?
  372. ;;
  373. drop)
  374. ser_drop $DBNAME $SQL_USER
  375. exit $?
  376. ;;
  377. reinit)
  378. ser_drop $DBNAME $SQL_USER
  379. ret=$?
  380. if [ "$ret" -ne 0 ]; then
  381. exit $ret
  382. fi
  383. ser_create $DBNAME $SQL_USER
  384. exit $?
  385. ;;
  386. *)
  387. usage
  388. exit 1;
  389. ;;
  390. esac