2 # 1) Create a database using the "CREATE DATABASE" mysql command.
3 # 2) Then, execute this script from command prompt with a command like this:
4 # mysql -h host -u user -p -D db_name < mysql.sql
6 # create database timetracker character set = 'utf8';
12 # Structure for table tt_groups. A team is a group of users for whom we are tracking work time.
13 # This table stores settings common to all group members such as language, week start day, etc.
15 CREATE TABLE `tt_groups` (
16 `id` int(11) NOT NULL auto_increment, # group id
17 `parent_id` int(11) default NULL, # parent group id
18 `org_id` int(11) default NULL, # organization id (id of top group)
19 `name` varchar(80) default NULL, # group name
20 `currency` varchar(7) default NULL, # currency symbol
21 `decimal_mark` char(1) NOT NULL default '.', # separator in decimals
22 `lang` varchar(10) NOT NULL default 'en', # language
23 `date_format` varchar(20) NOT NULL default '%Y-%m-%d', # date format
24 `time_format` varchar(20) NOT NULL default '%H:%M', # time format
25 `week_start` smallint(2) NOT NULL default 0, # Week start day, 0 == Sunday.
26 `tracking_mode` smallint(2) NOT NULL default 1, # tracking mode ("time", "projects" or "projects and tasks")
27 `project_required` smallint(2) NOT NULL default 0, # whether a project selection is required or optional
28 `task_required` smallint(2) NOT NULL default 0, # whether a task selection is required or optional
29 `record_type` smallint(2) NOT NULL default 0, # time record type ("start and finish", "duration", or both)
30 `bcc_email` varchar(100) default NULL, # bcc email to copy all reports to
31 `allow_ip` varchar(255) default NULL, # specification from where users are allowed access
32 `plugins` varchar(255) default NULL, # a list of enabled plugins for team
33 `lock_spec` varchar(255) default NULL, # Cron specification for record locking,
34 # for example: "0 10 * * 1" for "weekly on Mon at 10:00".
35 `workday_minutes` smallint(4) default 480, # number of work minutes in a regular working day
36 `custom_logo` tinyint(4) default 0, # whether to use a custom logo or not
37 `config` text default NULL, # miscellaneous group configuration settings
38 `created` datetime default NULL, # creation timestamp
39 `created_ip` varchar(45) default NULL, # creator ip
40 `created_by` int(11) default NULL, # creator user_id
41 `modified` datetime default NULL, # modification timestamp
42 `modified_ip` varchar(45) default NULL, # modifier ip
43 `modified_by` int(11) default NULL, # modifier user_id
44 `status` tinyint(4) default 1, # group status
50 # Structure for table tt_roles. This table stores customized team roles.
52 CREATE TABLE `tt_roles` (
53 `id` int(11) NOT NULL auto_increment, # Role id. Identifies roles for all groups on the server.
54 `group_id` int(11) NOT NULL, # Group id the role is defined for.
55 `name` varchar(80) default NULL, # Role name - custom role name. In case we are editing a
56 # predefined role (USER, etc.), we can rename the role here.
57 `description` varchar(255) default NULL, # Role description.
58 `rank` int(11) default 0, # Role rank, an integer value between 0-324. Predefined role ranks:
59 # USER - 4, CLIENT - 16, COMANAGER - 68, MANAGER - 324.
60 # Rank is used to determine what "lesser roles" are in each group
61 # for sutuations such as "manage_users".
62 # It also identifies a role within a team (by its "rank").
63 # Value of rank is to be used in role field in tt_users table,
64 # just like standard roles now.
65 `rights` text default NULL, # Comma-separated list of rights assigned to a role.
66 # NULL here for predefined roles (4, 16, 68, 324 - manager)
67 # means a hard-coded set of default access rights.
68 `status` tinyint(4) default 1, # Role status.
72 # Create an index that guarantees unique active and inactive role ranks in each group.
73 create unique index role_idx on tt_roles(group_id, rank, status);
75 # Insert site-wide roles - site administrator and top manager.
76 INSERT INTO `tt_roles` (`group_id`, `name`, `rank`, `rights`) VALUES (0, 'Site administrator', 1024, 'administer_site');
77 INSERT INTO `tt_roles` (`group_id`, `name`, `rank`, `rights`) VALUES (0, 'Top manager', 512, 'track_own_time,track_own_expenses,view_own_reports,view_own_charts,view_own_invoices,view_own_projects,manage_own_settings,view_users,track_time,track_expenses,view_reports,view_charts,override_punch_mode,override_own_punch_mode,override_date_lock,override_own_date_lock,swap_roles,approve_timesheets,manage_own_account,manage_users,manage_projects,manage_tasks,manage_custom_fields,manage_clients,manage_invoices,override_allow_ip,view_all_reports,manage_features,manage_basic_settings,manage_advanced_settings,manage_roles,export_data,manage_subgroups');
81 # Structure for table tt_users. This table is used to store user properties.
83 CREATE TABLE `tt_users` (
84 `id` int(11) NOT NULL auto_increment, # user id
85 `login` varchar(50) COLLATE utf8_bin NOT NULL, # user login
86 `password` varchar(50) default NULL, # password hash
87 `name` varchar(100) default NULL, # user name
88 `group_id` int(11) NOT NULL, # group id
89 `role_id` int(11) default NULL, # role id
90 `client_id` int(11) default NULL, # client id for "client" user role
91 `rate` float(6,2) NOT NULL default '0.00', # default hourly rate
92 `email` varchar(100) default NULL, # user email
93 `created` datetime default NULL, # creation timestamp
94 `created_ip` varchar(45) default NULL, # creator ip
95 `created_by` int(11) default NULL, # creator user_id (null for self)
96 `modified` datetime default NULL, # modification timestamp
97 `modified_ip` varchar(45) default NULL, # modifier ip
98 `modified_by` int(11) default NULL, # modifier user_id
99 `accessed` datetime default NULL, # last access timestamp
100 `accessed_ip` varchar(45) default NULL, # last access ip
101 `status` tinyint(4) default 1, # user status
105 # Create an index that guarantees unique active and inactive logins.
106 create unique index login_idx on tt_users(login, status);
108 # Create admin account with password 'secret'. Admin is a superuser, who can create teams.
109 DELETE from `tt_users` WHERE login = 'admin';
110 INSERT INTO `tt_users` (`login`, `password`, `name`, `group_id`, `role_id`) VALUES ('admin', md5('secret'), 'Admin', '0', (select id from tt_roles where rank = 1024));
114 # Structure for table tt_projects.
116 CREATE TABLE `tt_projects` (
117 `id` int(11) NOT NULL auto_increment, # project id
118 `group_id` int(11) NOT NULL, # group id
119 `name` varchar(80) COLLATE utf8_bin NOT NULL, # project name
120 `description` varchar(255) default NULL, # project description
121 `tasks` text default NULL, # comma-separated list of task ids associated with this project
122 `status` tinyint(4) default 1, # project status
126 # Create an index that guarantees unique active and inactive projects per group.
127 create unique index project_idx on tt_projects(group_id, name, status);
131 # Structure for table tt_tasks.
133 CREATE TABLE `tt_tasks` (
134 `id` int(11) NOT NULL auto_increment, # task id
135 `group_id` int(11) NOT NULL, # group id
136 `name` varchar(80) COLLATE utf8_bin NOT NULL, # task name
137 `description` varchar(255) default NULL, # task description
138 `status` tinyint(4) default 1, # task status
142 # Create an index that guarantees unique active and inactive tasks per group.
143 create unique index task_idx on tt_tasks(group_id, name, status);
147 # Structure for table tt_user_project_binds. This table maps users to assigned projects.
149 CREATE TABLE `tt_user_project_binds` (
150 `id` int(11) NOT NULL auto_increment, # bind id
151 `user_id` int(11) NOT NULL, # user id
152 `project_id` int(11) NOT NULL, # project id
153 `rate` float(6,2) default '0.00', # rate for this user when working on this project
154 `status` tinyint(4) default 1, # bind status
158 # Create an index that guarantees unique user to project binds.
159 create unique index bind_idx on tt_user_project_binds(user_id, project_id);
163 # Structure for table tt_project_task_binds. This table maps projects to assigned tasks.
165 CREATE TABLE `tt_project_task_binds` (
166 `project_id` int(11) NOT NULL, # project id
167 `task_id` int(11) NOT NULL # task id
170 # Indexes for tt_project_task_binds.
171 create index project_idx on tt_project_task_binds(project_id);
172 create index task_idx on tt_project_task_binds(task_id);
176 # Structure for table tt_log. This is the table where time entries for users are stored.
177 # If you use custom fields, additional info for each record may exist in tt_custom_field_log.
179 CREATE TABLE `tt_log` (
180 `id` bigint NOT NULL auto_increment, # time record id
181 `user_id` int(11) NOT NULL, # user id
182 `date` date NOT NULL, # date the record is for
183 `start` time default NULL, # record start time (for example, 09:00)
184 `duration` time default NULL, # record duration (for example, 1 hour)
185 `client_id` int(11) default NULL, # client id
186 `project_id` int(11) default NULL, # project id
187 `task_id` int(11) default NULL, # task id
188 `invoice_id` int(11) default NULL, # invoice id
189 `comment` text, # user provided comment for time record
190 `billable` tinyint(4) default 0, # whether the record is billable or not
191 `paid` tinyint(4) default 0, # whether the record is paid
192 `created` datetime default NULL, # creation timestamp
193 `created_ip` varchar(45) default NULL, # creator ip
194 `created_by` int(11) default NULL, # creator user_id
195 `modified` datetime default NULL, # modification timestamp
196 `modified_ip` varchar(45) default NULL, # modifier ip
197 `modified_by` int(11) default NULL, # modifier user_id
198 `status` tinyint(4) default 1, # time record status
202 # Create indexes on tt_log for performance.
203 create index date_idx on tt_log(date);
204 create index user_idx on tt_log(user_id);
205 create index client_idx on tt_log(client_id);
206 create index invoice_idx on tt_log(invoice_id);
207 create index project_idx on tt_log(project_id);
208 create index task_idx on tt_log(task_id);
212 # Structure for table tt_invoices. Invoices are issued to clients for billable work.
214 CREATE TABLE `tt_invoices` (
215 `id` int(11) NOT NULL auto_increment, # invoice id
216 `group_id` int(11) NOT NULL, # group id
217 `name` varchar(80) COLLATE utf8_bin NOT NULL, # invoice name
218 `date` date NOT NULL, # invoice date
219 `client_id` int(11) NOT NULL, # client id
220 `status` tinyint(4) default 1, # invoice status
224 # Create an index that guarantees unique invoice names per team.
225 create unique index name_idx on tt_invoices(group_id, name, status);
229 # Structure for table tt_tmp_refs. Used for reset password mechanism.
231 CREATE TABLE `tt_tmp_refs` (
232 `created` datetime default NULL, # creation timestamp
233 `ref` char(32) NOT NULL default '', # unique reference for user, used in urls
234 `user_id` int(11) NOT NULL # user id
239 # Structure for table tt_fav_reports. Favorite reports are pre-configured report configurations.
241 CREATE TABLE `tt_fav_reports` (
242 `id` int(11) NOT NULL auto_increment, # favorite report id
243 `name` varchar(200) NOT NULL, # favorite report name
244 `user_id` int(11) NOT NULL, # user id favorite report belongs to
245 `report_spec` text default NULL, # future replacement field for all report settings
246 `client_id` int(11) default NULL, # client id (if selected)
247 `cf_1_option_id` int(11) default NULL, # custom field 1 option id (if selected)
248 `project_id` int(11) default NULL, # project id (if selected)
249 `task_id` int(11) default NULL, # task id (if selected)
250 `billable` tinyint(4) default NULL, # whether to include billable, not billable, or all records
251 `invoice` tinyint(4) default NULL, # whether to include invoiced, not invoiced, or all records
252 `paid_status` tinyint(4) default NULL, # whether to include paid, not paid, or all records
253 `users` text default NULL, # Comma-separated list of user ids. Nothing here means "all" users.
254 `period` tinyint(4) default NULL, # selected period type for report
255 `period_start` date default NULL, # period start
256 `period_end` date default NULL, # period end
257 `show_client` tinyint(4) NOT NULL default 0, # whether to show client column
258 `show_invoice` tinyint(4) NOT NULL default 0, # whether to show invoice column
259 `show_paid` tinyint(4) NOT NULL default 0, # whether to show paid column
260 `show_ip` tinyint(4) NOT NULL default 0, # whether to show ip column
261 `show_project` tinyint(4) NOT NULL default 0, # whether to show project column
262 `show_start` tinyint(4) NOT NULL default 0, # whether to show start field
263 `show_duration` tinyint(4) NOT NULL default 0, # whether to show duration field
264 `show_cost` tinyint(4) NOT NULL default 0, # whether to show cost field
265 `show_task` tinyint(4) NOT NULL default 0, # whether to show task column
266 `show_end` tinyint(4) NOT NULL default 0, # whether to show end field
267 `show_note` tinyint(4) NOT NULL default 0, # whether to show note column
268 `show_custom_field_1` tinyint(4) NOT NULL default 0, # whether to show custom field 1
269 `show_totals_only` tinyint(4) NOT NULL default 0, # whether to show totals only
270 `group_by` varchar(20) default NULL, # group by field
271 `status` tinyint(4) default 1, # favorite report status
277 # Structure for table tt_cron. It is used to email favorite reports on schedule.
279 CREATE TABLE `tt_cron` (
280 `id` int(11) NOT NULL auto_increment, # entry id
281 `group_id` int(11) NOT NULL, # group id
282 `cron_spec` varchar(255) NOT NULL, # cron specification, "0 1 * * *" for "daily at 01:00"
283 `last` int(11) default NULL, # UNIX timestamp of when job was last run
284 `next` int(11) default NULL, # UNIX timestamp of when to run next job
285 `report_id` int(11) default NULL, # report id from tt_fav_reports, a report to mail on schedule
286 `email` varchar(100) default NULL, # email to send results to
287 `cc` varchar(100) default NULL, # cc email to send results to
288 `subject` varchar(100) default NULL, # email subject
289 `report_condition` varchar(255) default NULL, # report condition, "count > 0" for sending not empty reports
290 `status` tinyint(4) default 1, # entry status
296 # Structure for table tt_clients. A client is an entity for whom work is performed and who may be invoiced.
298 CREATE TABLE `tt_clients` (
299 `id` int(11) NOT NULL AUTO_INCREMENT, # client id
300 `group_id` int(11) NOT NULL, # group id
301 `name` varchar(80) COLLATE utf8_bin NOT NULL, # client name
302 `address` varchar(255) default NULL, # client address
303 `tax` float(6,2) default '0.00', # applicable tax for this client
304 `projects` text default NULL, # comma-separated list of project ids assigned to this client
305 `status` tinyint(4) default 1, # client status
309 # Create an index that guarantees unique active and inactive clients per team.
310 create unique index client_name_idx on tt_clients(group_id, name, status);
314 # Structure for table tt_client_project_binds. This table maps clients to assigned projects.
316 CREATE TABLE `tt_client_project_binds` (
317 `client_id` int(11) NOT NULL, # client id
318 `project_id` int(11) NOT NULL # project id
321 # Indexes for tt_client_project_binds.
322 create index client_idx on tt_client_project_binds(client_id);
323 create index project_idx on tt_client_project_binds(project_id);
327 # Structure for table tt_config. This table is used to store configuration info for users.
328 # For example, last_report_email parameter stores an email for user last report was emailed to.
330 CREATE TABLE `tt_config` (
331 `user_id` int(11) NOT NULL, # user id
332 `param_name` varchar(32) NOT NULL, # parameter name
333 `param_value` varchar(80) default NULL # parameter value
336 # Create an index that guarantees unique parameter names per user.
337 create unique index param_idx on tt_config(user_id, param_name);
340 # Below are the tables used by CustomFields plugin.
343 # Structure for table tt_custom_fields. This table contains definitions of custom fields.
345 CREATE TABLE `tt_custom_fields` (
346 `id` int(11) NOT NULL auto_increment, # custom field id
347 `group_id` int(11) NOT NULL, # group id
348 `type` tinyint(4) NOT NULL default 0, # custom field type (text or dropdown)
349 `label` varchar(32) NOT NULL default '', # custom field label
350 `required` tinyint(4) default 0, # whether this custom field is mandatory for time records
351 `status` tinyint(4) default 1, # custom field status
357 # Structure for table tt_custom_field_options. This table defines options for dropdown custom fields.
359 CREATE TABLE `tt_custom_field_options` (
360 `id` int(11) NOT NULL auto_increment, # option id
361 `field_id` int(11) NOT NULL, # custom field id
362 `value` varchar(32) NOT NULL default '', # option value
368 # Structure for table tt_custom_field_log.
369 # This table supplements tt_log and contains custom field values for records.
371 CREATE TABLE `tt_custom_field_log` (
372 `id` bigint NOT NULL auto_increment, # cutom field log id
373 `log_id` bigint NOT NULL, # id of a record in tt_log this record corresponds to
374 `field_id` int(11) NOT NULL, # custom field id
375 `option_id` int(11) default NULL, # Option id. Used for dropdown custom fields.
376 `value` varchar(255) default NULL, # Text value. Used for text custom fields.
377 `status` tinyint(4) default 1, # custom field log entry status
383 # Structure for table tt_expense_items.
384 # This table lists expense items.
386 CREATE TABLE `tt_expense_items` (
387 `id` bigint NOT NULL auto_increment, # expense item id
388 `date` date NOT NULL, # date the record is for
389 `user_id` int(11) NOT NULL, # user id the expense item is reported by
390 `client_id` int(11) default NULL, # client id
391 `project_id` int(11) default NULL, # project id
392 `name` text NOT NULL, # expense item name (what is an expense for)
393 `cost` decimal(10,2) default '0.00', # item cost (including taxes, etc.)
394 `invoice_id` int(11) default NULL, # invoice id
395 `paid` tinyint(4) default 0, # whether the item is paid
396 `created` datetime default NULL, # creation timestamp
397 `created_ip` varchar(45) default NULL, # creator ip
398 `created_by` int(11) default NULL, # creator user_id
399 `modified` datetime default NULL, # modification timestamp
400 `modified_ip` varchar(45) default NULL, # modifier ip
401 `modified_by` int(11) default NULL, # modifier user_id
402 `status` tinyint(4) default 1, # item status
406 # Create indexes on tt_expense_items for performance.
407 create index date_idx on tt_expense_items(date);
408 create index user_idx on tt_expense_items(user_id);
409 create index client_idx on tt_expense_items(client_id);
410 create index project_idx on tt_expense_items(project_id);
411 create index invoice_idx on tt_expense_items(invoice_id);
415 # Structure for table tt_predefined_expenses.
416 # This table keeps names and costs for predefined expenses.
418 CREATE TABLE `tt_predefined_expenses` (
419 `id` int(11) NOT NULL auto_increment, # predefined expense id
420 `group_id` int(11) NOT NULL, # group id
421 `name` varchar(255) NOT NULL, # predefined expense name, such as mileage
422 `cost` decimal(10,2) default '0.00', # cost for one unit
428 # Structure for table tt_monthly_quotas.
429 # This table keeps monthly work hour quotas for groups.
431 CREATE TABLE `tt_monthly_quotas` (
432 `group_id` int(11) NOT NULL, # group id
433 `year` smallint(5) UNSIGNED NOT NULL, # quota year
434 `month` tinyint(3) UNSIGNED NOT NULL, # quota month
435 `minutes` int(11) default NULL, # quota in minutes in specified month and year
436 PRIMARY KEY (`group_id`,`year`,`month`)
441 # Structure for table tt_site_config. This table stores configuration data
442 # for Time Tracker site as a whole.
443 # For example, database version, code version, site language, etc.
445 CREATE TABLE `tt_site_config` (
446 `param_name` varchar(32) NOT NULL, # parameter name
447 `param_value` text default NULL, # parameter value
448 `created` datetime default NULL, # creation timestamp
449 `modified` datetime default NULL, # modification timestamp
450 PRIMARY KEY (`param_name`)
453 INSERT INTO `tt_site_config` (`param_name`, `param_value`, `created`) VALUES ('version_db', '1.17.83', now()); # TODO: change when structure changes.