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 = 'utf8mb4';
12 # Structure for table tt_groups. A group is a unit 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 `password_complexity` varchar(64) default NULL, # password example that defines required complexity
33 `plugins` varchar(255) default NULL, # a list of enabled plugins for group
34 `lock_spec` varchar(255) default NULL, # Cron specification for record locking,
35 # for example: "0 10 * * 1" for "weekly on Mon at 10:00".
36 `workday_minutes` smallint(4) default 480, # number of work minutes in a regular working day
37 `custom_logo` tinyint(4) default 0, # whether to use a custom logo or not
38 `config` text default NULL, # miscellaneous group configuration settings
39 `created` datetime default NULL, # creation timestamp
40 `created_ip` varchar(45) default NULL, # creator ip
41 `created_by` int(11) default NULL, # creator user_id
42 `modified` datetime default NULL, # modification timestamp
43 `modified_ip` varchar(45) default NULL, # modifier ip
44 `modified_by` int(11) default NULL, # modifier user_id
45 `status` tinyint(4) default 1, # group status
51 # Structure for table tt_roles. This table stores group roles.
53 CREATE TABLE `tt_roles` (
54 `id` int(11) NOT NULL auto_increment, # Role id. Identifies roles for all groups on the server.
55 `group_id` int(11) NOT NULL, # Group id the role is defined for.
56 `org_id` int(11) default NULL, # Organization id.
57 `name` varchar(80) default NULL, # Role name - custom role name. In case we are editing a
58 # predefined role (USER, etc.), we can rename the role here.
59 `description` varchar(255) default NULL, # Role description.
60 `rank` int(11) default 0, # Role rank, an integer value between 0-512. Predefined role ranks:
61 # User - 4, Supervisor - 12, Client - 16,
62 # Co-manager - 68, Manager - 324, Top manager - 512.
63 # Rank is used to determine what "lesser roles" are in each group
64 # for situations such as "manage_users".
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,view_own_tasks,manage_own_settings,view_users,track_time,track_expenses,view_reports,view_charts,view_own_clients,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,manage_basic_settings,view_all_reports,manage_features,manage_advanced_settings,manage_roles,export_data,manage_subgroups,delete_group');
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 utf8mb4_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 `org_id` int(11) default NULL, # organization id
90 `role_id` int(11) default NULL, # role id
91 `client_id` int(11) default NULL, # client id for "client" user role
92 `rate` float(6,2) NOT NULL default '0.00', # default hourly rate
93 `email` varchar(100) default NULL, # user email
94 `created` datetime default NULL, # creation timestamp
95 `created_ip` varchar(45) default NULL, # creator ip
96 `created_by` int(11) default NULL, # creator user_id (null for self)
97 `modified` datetime default NULL, # modification timestamp
98 `modified_ip` varchar(45) default NULL, # modifier ip
99 `modified_by` int(11) default NULL, # modifier user_id
100 `accessed` datetime default NULL, # last access timestamp
101 `accessed_ip` varchar(45) default NULL, # last access ip
102 `status` tinyint(4) default 1, # user status
106 # Create an index that guarantees unique active and inactive logins.
107 create unique index login_idx on tt_users(login, status);
109 # Create admin account with password 'secret'. Admin is a superuser who can create groups.
110 DELETE from `tt_users` WHERE login = 'admin';
111 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));
115 # Structure for table tt_projects.
117 CREATE TABLE `tt_projects` (
118 `id` int(11) NOT NULL auto_increment, # project id
119 `group_id` int(11) NOT NULL, # group id
120 `org_id` int(11) default NULL, # organization id
121 `name` varchar(80) COLLATE utf8mb4_bin NOT NULL, # project name
122 `description` varchar(255) default NULL, # project description
123 `tasks` text default NULL, # comma-separated list of task ids associated with this project
124 `status` tinyint(4) default 1, # project status
128 # Create an index that guarantees unique active and inactive projects per group.
129 create unique index project_idx on tt_projects(group_id, name, status);
133 # Structure for table tt_tasks.
135 CREATE TABLE `tt_tasks` (
136 `id` int(11) NOT NULL auto_increment, # task id
137 `group_id` int(11) NOT NULL, # group id
138 `org_id` int(11) default NULL, # organization id
139 `name` varchar(80) COLLATE utf8mb4_bin NOT NULL, # task name
140 `description` varchar(255) default NULL, # task description
141 `status` tinyint(4) default 1, # task status
145 # Create an index that guarantees unique active and inactive tasks per group.
146 create unique index task_idx on tt_tasks(group_id, name, status);
150 # Structure for table tt_user_project_binds. This table maps users to assigned projects.
152 CREATE TABLE `tt_user_project_binds` (
153 `id` int(11) NOT NULL auto_increment, # bind id
154 `user_id` int(11) NOT NULL, # user id
155 `project_id` int(11) NOT NULL, # project id
156 `group_id` int(11) default NULL, # group id
157 `org_id` int(11) default NULL, # organization id
158 `rate` float(6,2) default '0.00', # rate for this user when working on this project
159 `status` tinyint(4) default 1, # bind status
163 # Create an index that guarantees unique user to project binds.
164 create unique index bind_idx on tt_user_project_binds(user_id, project_id);
168 # Structure for table tt_project_task_binds. This table maps projects to assigned tasks.
170 CREATE TABLE `tt_project_task_binds` (
171 `project_id` int(11) NOT NULL, # project id
172 `task_id` int(11) NOT NULL, # task id
173 `group_id` int(11) default NULL, # group id
174 `org_id` int(11) default NULL # organization id
177 # Indexes for tt_project_task_binds.
178 create index project_idx on tt_project_task_binds(project_id);
179 create index task_idx on tt_project_task_binds(task_id);
183 # Structure for table tt_log. This is the table where time entries for users are stored.
184 # If you use custom fields, additional info for each record may exist in tt_custom_field_log.
186 CREATE TABLE `tt_log` (
187 `id` bigint NOT NULL auto_increment, # time record id
188 `user_id` int(11) NOT NULL, # user id
189 `group_id` int(11) default NULL, # group id
190 `org_id` int(11) default NULL, # organization id
191 `date` date NOT NULL, # date the record is for
192 `start` time default NULL, # record start time (for example, 09:00)
193 `duration` time default NULL, # record duration (for example, 1 hour)
194 `client_id` int(11) default NULL, # client id
195 `project_id` int(11) default NULL, # project id
196 `task_id` int(11) default NULL, # task id
197 `invoice_id` int(11) default NULL, # invoice id
198 `comment` text, # user provided comment for time record
199 `billable` tinyint(4) default 0, # whether the record is billable or not
200 `paid` tinyint(4) default 0, # whether the record is paid
201 `created` datetime default NULL, # creation timestamp
202 `created_ip` varchar(45) default NULL, # creator ip
203 `created_by` int(11) default NULL, # creator user_id
204 `modified` datetime default NULL, # modification timestamp
205 `modified_ip` varchar(45) default NULL, # modifier ip
206 `modified_by` int(11) default NULL, # modifier user_id
207 `status` tinyint(4) default 1, # time record status
211 # Create indexes on tt_log for performance.
212 create index date_idx on tt_log(date);
213 create index user_idx on tt_log(user_id);
214 create index group_idx on tt_log(group_id);
215 create index client_idx on tt_log(client_id);
216 create index invoice_idx on tt_log(invoice_id);
217 create index project_idx on tt_log(project_id);
218 create index task_idx on tt_log(task_id);
222 # Structure for table tt_invoices. Invoices are issued to clients for billable work.
224 CREATE TABLE `tt_invoices` (
225 `id` int(11) NOT NULL auto_increment, # invoice id
226 `group_id` int(11) NOT NULL, # group id
227 `org_id` int(11) default NULL, # organization id
228 `name` varchar(80) COLLATE utf8mb4_bin NOT NULL, # invoice name
229 `date` date NOT NULL, # invoice date
230 `client_id` int(11) NOT NULL, # client id
231 `status` tinyint(4) default 1, # invoice status
235 # Create an index that guarantees unique invoice names per group.
236 create unique index name_idx on tt_invoices(group_id, name, status);
240 # Structure for table tt_tmp_refs. Used for reset password mechanism.
242 CREATE TABLE `tt_tmp_refs` (
243 `created` datetime default NULL, # creation timestamp
244 `ref` char(32) NOT NULL default '', # unique reference for user, used in urls
245 `user_id` int(11) NOT NULL # user id
250 # Structure for table tt_fav_reports. Favorite reports are pre-configured report configurations.
252 CREATE TABLE `tt_fav_reports` (
253 `id` int(11) NOT NULL auto_increment, # favorite report id
254 `name` varchar(200) NOT NULL, # favorite report name
255 `user_id` int(11) NOT NULL, # user id favorite report belongs to
256 `report_spec` text default NULL, # future replacement field for all report settings
257 `client_id` int(11) default NULL, # client id (if selected)
258 `cf_1_option_id` int(11) default NULL, # custom field 1 option id (if selected)
259 `project_id` int(11) default NULL, # project id (if selected)
260 `task_id` int(11) default NULL, # task id (if selected)
261 `billable` tinyint(4) default NULL, # whether to include billable, not billable, or all records
262 `invoice` tinyint(4) default NULL, # whether to include invoiced, not invoiced, or all records
263 `paid_status` tinyint(4) default NULL, # whether to include paid, not paid, or all records
264 `users` text default NULL, # Comma-separated list of user ids. Nothing here means "all" users.
265 `period` tinyint(4) default NULL, # selected period type for report
266 `period_start` date default NULL, # period start
267 `period_end` date default NULL, # period end
268 `show_client` tinyint(4) NOT NULL default 0, # whether to show client column
269 `show_invoice` tinyint(4) NOT NULL default 0, # whether to show invoice column
270 `show_paid` tinyint(4) NOT NULL default 0, # whether to show paid column
271 `show_ip` tinyint(4) NOT NULL default 0, # whether to show ip column
272 `show_project` tinyint(4) NOT NULL default 0, # whether to show project column
273 `show_start` tinyint(4) NOT NULL default 0, # whether to show start field
274 `show_duration` tinyint(4) NOT NULL default 0, # whether to show duration field
275 `show_cost` tinyint(4) NOT NULL default 0, # whether to show cost field
276 `show_task` tinyint(4) NOT NULL default 0, # whether to show task column
277 `show_end` tinyint(4) NOT NULL default 0, # whether to show end field
278 `show_note` tinyint(4) NOT NULL default 0, # whether to show note column
279 `show_custom_field_1` tinyint(4) NOT NULL default 0, # whether to show custom field 1
280 `show_work_units` tinyint(4) NOT NULL default 0, # whether to show work units
281 `show_totals_only` tinyint(4) NOT NULL default 0, # whether to show totals only
282 `group_by1` varchar(20) default NULL, # group by field 1
283 `group_by2` varchar(20) default NULL, # group by field 2
284 `group_by3` varchar(20) default NULL, # group by field 3
285 `status` tinyint(4) default 1, # favorite report status
291 # Structure for table tt_cron. It is used to email favorite reports on schedule.
293 CREATE TABLE `tt_cron` (
294 `id` int(11) NOT NULL auto_increment, # entry id
295 `group_id` int(11) NOT NULL, # group id
296 `cron_spec` varchar(255) NOT NULL, # cron specification, "0 1 * * *" for "daily at 01:00"
297 `last` int(11) default NULL, # UNIX timestamp of when job was last run
298 `next` int(11) default NULL, # UNIX timestamp of when to run next job
299 `report_id` int(11) default NULL, # report id from tt_fav_reports, a report to mail on schedule
300 `email` varchar(100) default NULL, # email to send results to
301 `cc` varchar(100) default NULL, # cc email to send results to
302 `subject` varchar(100) default NULL, # email subject
303 `report_condition` varchar(255) default NULL, # report condition, "count > 0" for sending not empty reports
304 `status` tinyint(4) default 1, # entry status
310 # Structure for table tt_clients. A client is an entity for whom work is performed and who may be invoiced.
312 CREATE TABLE `tt_clients` (
313 `id` int(11) NOT NULL AUTO_INCREMENT, # client id
314 `group_id` int(11) NOT NULL, # group id
315 `org_id` int(11) default NULL, # organization id
316 `name` varchar(80) COLLATE utf8mb4_bin NOT NULL, # client name
317 `address` varchar(255) default NULL, # client address
318 `tax` float(6,2) default '0.00', # applicable tax for this client
319 `projects` text default NULL, # comma-separated list of project ids assigned to this client
320 `status` tinyint(4) default 1, # client status
324 # Create an index that guarantees unique active and inactive clients per group.
325 create unique index client_name_idx on tt_clients(group_id, name, status);
329 # Structure for table tt_client_project_binds. This table maps clients to assigned projects.
331 CREATE TABLE `tt_client_project_binds` (
332 `client_id` int(11) NOT NULL, # client id
333 `project_id` int(11) NOT NULL # project id
336 # Indexes for tt_client_project_binds.
337 create index client_idx on tt_client_project_binds(client_id);
338 create index project_idx on tt_client_project_binds(project_id);
342 # Structure for table tt_config. This table is used to store configuration info for users.
343 # For example, last_report_email parameter stores an email for user last report was emailed to.
345 CREATE TABLE `tt_config` (
346 `user_id` int(11) NOT NULL, # user id
347 `param_name` varchar(32) NOT NULL, # parameter name
348 `param_value` varchar(80) default NULL # parameter value
351 # Create an index that guarantees unique parameter names per user.
352 create unique index param_idx on tt_config(user_id, param_name);
355 # Below are the tables used by CustomFields plugin.
358 # Structure for table tt_custom_fields. This table contains definitions of custom fields.
360 CREATE TABLE `tt_custom_fields` (
361 `id` int(11) NOT NULL auto_increment, # custom field id
362 `group_id` int(11) NOT NULL, # group id
363 `type` tinyint(4) NOT NULL default 0, # custom field type (text or dropdown)
364 `label` varchar(32) NOT NULL default '', # custom field label
365 `required` tinyint(4) default 0, # whether this custom field is mandatory for time records
366 `status` tinyint(4) default 1, # custom field status
372 # Structure for table tt_custom_field_options. This table defines options for dropdown custom fields.
374 CREATE TABLE `tt_custom_field_options` (
375 `id` int(11) NOT NULL auto_increment, # option id
376 `field_id` int(11) NOT NULL, # custom field id
377 `value` varchar(32) NOT NULL default '', # option value
383 # Structure for table tt_custom_field_log.
384 # This table supplements tt_log and contains custom field values for records.
386 CREATE TABLE `tt_custom_field_log` (
387 `id` bigint NOT NULL auto_increment, # cutom field log id
388 `log_id` bigint NOT NULL, # id of a record in tt_log this record corresponds to
389 `field_id` int(11) NOT NULL, # custom field id
390 `option_id` int(11) default NULL, # Option id. Used for dropdown custom fields.
391 `value` varchar(255) default NULL, # Text value. Used for text custom fields.
392 `status` tinyint(4) default 1, # custom field log entry status
396 create index log_idx on tt_custom_field_log(log_id);
400 # Structure for table tt_expense_items.
401 # This table lists expense items.
403 CREATE TABLE `tt_expense_items` (
404 `id` bigint NOT NULL auto_increment, # expense item id
405 `date` date NOT NULL, # date the record is for
406 `user_id` int(11) NOT NULL, # user id the expense item is reported by
407 `group_id` int(11) default NULL, # group id
408 `client_id` int(11) default NULL, # client id
409 `project_id` int(11) default NULL, # project id
410 `name` text NOT NULL, # expense item name (what is an expense for)
411 `cost` decimal(10,2) default '0.00', # item cost (including taxes, etc.)
412 `invoice_id` int(11) default NULL, # invoice id
413 `paid` tinyint(4) default 0, # whether the item is paid
414 `created` datetime default NULL, # creation timestamp
415 `created_ip` varchar(45) default NULL, # creator ip
416 `created_by` int(11) default NULL, # creator user_id
417 `modified` datetime default NULL, # modification timestamp
418 `modified_ip` varchar(45) default NULL, # modifier ip
419 `modified_by` int(11) default NULL, # modifier user_id
420 `status` tinyint(4) default 1, # item status
424 # Create indexes on tt_expense_items for performance.
425 create index date_idx on tt_expense_items(date);
426 create index user_idx on tt_expense_items(user_id);
427 create index group_idx on tt_expense_items(group_id);
428 create index client_idx on tt_expense_items(client_id);
429 create index project_idx on tt_expense_items(project_id);
430 create index invoice_idx on tt_expense_items(invoice_id);
434 # Structure for table tt_predefined_expenses.
435 # This table keeps names and costs for predefined expenses.
437 CREATE TABLE `tt_predefined_expenses` (
438 `id` int(11) NOT NULL auto_increment, # predefined expense id
439 `group_id` int(11) NOT NULL, # group id
440 `name` varchar(255) NOT NULL, # predefined expense name, such as mileage
441 `cost` decimal(10,2) default '0.00', # cost for one unit
447 # Structure for table tt_monthly_quotas.
448 # This table keeps monthly work hour quotas for groups.
450 CREATE TABLE `tt_monthly_quotas` (
451 `group_id` int(11) NOT NULL, # group id
452 `org_id` int(11) default NULL # organization id
453 `year` smallint(5) UNSIGNED NOT NULL, # quota year
454 `month` tinyint(3) UNSIGNED NOT NULL, # quota month
455 `minutes` int(11) default NULL, # quota in minutes in specified month and year
456 PRIMARY KEY (`group_id`,`year`,`month`)
461 # Structure for table tt_site_config. This table stores configuration data
462 # for Time Tracker site as a whole.
463 # For example, database version, code version, site language, etc.
465 CREATE TABLE `tt_site_config` (
466 `param_name` varchar(32) NOT NULL, # parameter name
467 `param_value` text default NULL, # parameter value
468 `created` datetime default NULL, # creation timestamp
469 `modified` datetime default NULL, # modification timestamp
470 PRIMARY KEY (`param_name`)
473 INSERT INTO `tt_site_config` (`param_name`, `param_value`, `created`) VALUES ('version_db', '1.18.15', now()); # TODO: change when structure changes.