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_teams. A team is a group of users for whom we are tracking work time.
13 # This table stores settings common to all team members such as language, week start day, etc.
15 CREATE TABLE `tt_teams` (
16 `id` int(11) NOT NULL auto_increment, # team id
17 `timestamp` timestamp default CURRENT_TIMESTAMP, # modification timestamp
18 `name` varchar(80) default NULL, # team name
19 `currency` varchar(7) default NULL, # team currency symbol
20 `decimal_mark` char(1) NOT NULL default '.', # separator in decimals
21 `lang` varchar(10) NOT NULL default 'en', # language
22 `date_format` varchar(20) NOT NULL default '%Y-%m-%d', # date format
23 `time_format` varchar(20) NOT NULL default '%H:%M', # time format
24 `week_start` smallint(2) NOT NULL default 0, # Week start day, 0 == Sunday.
25 `tracking_mode` smallint(2) NOT NULL default 1, # tracking mode ("time", "projects" or "projects and tasks")
26 `project_required` smallint(2) NOT NULL default 0, # whether a project selection is required or optional
27 `task_required` smallint(2) NOT NULL default 0, # whether a task selection is required or optional
28 `record_type` smallint(2) NOT NULL default 0, # time record type ("start and finish", "duration", or both)
29 `bcc_email` varchar(100) default NULL, # bcc email to copy all reports to
30 `plugins` varchar(255) default NULL, # a list of enabled plugins for team
31 `lock_spec` varchar(255) default NULL, # Cron specification for record locking,
32 # for example: "0 10 * * 1" for "weekly on Mon at 10:00".
33 `workday_minutes` smallint(4) default 480, # number of work minutes in a regular working day
34 `custom_logo` tinyint(4) default 0, # whether to use a custom logo or not
35 `config` text default NULL, # miscellaneous team configuration settings
36 `status` tinyint(4) default 1, # team status
42 # Structure for table tt_users. This table is used to store user properties.
44 CREATE TABLE `tt_users` (
45 `id` int(11) NOT NULL auto_increment, # user id
46 `timestamp` timestamp default CURRENT_TIMESTAMP, # modification timestamp
47 `login` varchar(50) COLLATE utf8_bin NOT NULL, # user login
48 `password` varchar(50) default NULL, # password hash
49 `name` varchar(100) default NULL, # user name
50 `team_id` int(11) NOT NULL, # team id
51 `role` int(11) default 4, # user role ("manager", "co-manager", "client", or "user")
52 `role_id` int(11) default NULL, # future replacement of role
53 `client_id` int(11) default NULL, # client id for "client" user role
54 `rate` float(6,2) NOT NULL default '0.00', # default hourly rate
55 `email` varchar(100) default NULL, # user email
56 `status` tinyint(4) default 1, # user status
60 # Create an index that guarantees unique active and inactive logins.
61 create unique index login_idx on tt_users(login, status);
63 # Create admin account with password 'secret'. Admin is a superuser, who can create teams.
64 DELETE from `tt_users` WHERE login = 'admin';
65 INSERT INTO `tt_users` (`login`, `password`, `name`, `team_id`, `role`) VALUES ('admin', md5('secret'), 'Admin', '0', '1024');
69 # Structure for table tt_projects.
71 CREATE TABLE `tt_projects` (
72 `id` int(11) NOT NULL auto_increment, # project id
73 `team_id` int(11) NOT NULL, # team id
74 `name` varchar(80) COLLATE utf8_bin NOT NULL, # project name
75 `description` varchar(255) default NULL, # project description
76 `tasks` text default NULL, # comma-separated list of task ids associated with this project
77 `status` tinyint(4) default 1, # project status
81 # Create an index that guarantees unique active and inactive projects per team.
82 create unique index project_idx on tt_projects(team_id, name, status);
86 # Structure for table tt_tasks.
88 CREATE TABLE `tt_tasks` (
89 `id` int(11) NOT NULL auto_increment, # task id
90 `team_id` int(11) NOT NULL, # team id
91 `name` varchar(80) COLLATE utf8_bin NOT NULL, # task name
92 `description` varchar(255) default NULL, # task description
93 `status` tinyint(4) default 1, # task status
97 # Create an index that guarantees unique active and inactive tasks per team.
98 create unique index task_idx on tt_tasks(team_id, name, status);
102 # Structure for table tt_user_project_binds. This table maps users to assigned projects.
104 CREATE TABLE `tt_user_project_binds` (
105 `id` int(11) NOT NULL auto_increment, # bind id
106 `user_id` int(11) NOT NULL, # user id
107 `project_id` int(11) NOT NULL, # project id
108 `rate` float(6,2) default '0.00', # rate for this user when working on this project
109 `status` tinyint(4) default 1, # bind status
113 # Create an index that guarantees unique user to project binds.
114 create unique index bind_idx on tt_user_project_binds(user_id, project_id);
118 # Structure for table tt_project_task_binds. This table maps projects to assigned tasks.
120 CREATE TABLE `tt_project_task_binds` (
121 `project_id` int(11) NOT NULL, # project id
122 `task_id` int(11) NOT NULL # task id
125 # Indexes for tt_project_task_binds.
126 create index project_idx on tt_project_task_binds(project_id);
127 create index task_idx on tt_project_task_binds(task_id);
131 # Structure for table tt_log. This is the table where time entries for users are stored.
132 # If you use custom fields, additional info for each record may exist in tt_custom_field_log.
134 CREATE TABLE `tt_log` (
135 `id` bigint NOT NULL auto_increment, # time record id
136 `timestamp` timestamp default CURRENT_TIMESTAMP, # modification timestamp
137 `user_id` int(11) NOT NULL, # user id
138 `date` date NOT NULL, # date the record is for
139 `start` time default NULL, # record start time (for example, 09:00)
140 `duration` time default NULL, # record duration (for example, 1 hour)
141 `client_id` int(11) default NULL, # client id
142 `project_id` int(11) default NULL, # project id
143 `task_id` int(11) default NULL, # task id
144 `invoice_id` int(11) default NULL, # invoice id
145 `comment` text, # user provided comment for time record
146 `billable` tinyint(4) default 0, # whether the record is billable or not
147 `paid` tinyint(4) default 0, # whether the record is paid
148 `status` tinyint(4) default 1, # time record status
152 # Create indexes on tt_log for performance.
153 create index date_idx on tt_log(date);
154 create index user_idx on tt_log(user_id);
155 create index client_idx on tt_log(client_id);
156 create index invoice_idx on tt_log(invoice_id);
157 create index project_idx on tt_log(project_id);
158 create index task_idx on tt_log(task_id);
162 # Structure for table tt_invoices. Invoices are issued to clients for billable work.
164 CREATE TABLE `tt_invoices` (
165 `id` int(11) NOT NULL auto_increment, # invoice id
166 `team_id` int(11) NOT NULL, # team id
167 `name` varchar(80) COLLATE utf8_bin NOT NULL, # invoice name
168 `date` date NOT NULL, # invoice date
169 `client_id` int(11) NOT NULL, # client id
170 `status` tinyint(4) default 1, # invoice status
174 # Create an index that guarantees unique invoice names per team.
175 create unique index name_idx on tt_invoices(team_id, name, status);
179 # Structure for table tt_tmp_refs. Used for reset password mechanism.
181 CREATE TABLE `tt_tmp_refs` (
182 `timestamp` timestamp default CURRENT_TIMESTAMP, # creation timestamp
183 `ref` char(32) NOT NULL default '', # unique reference for user, used in urls
184 `user_id` int(11) NOT NULL # user id
189 # Structure for table tt_fav_reports. Favorite reports are pre-configured report configurations.
191 CREATE TABLE `tt_fav_reports` (
192 `id` int(11) NOT NULL auto_increment, # favorite report id
193 `name` varchar(200) NOT NULL, # favorite report name
194 `user_id` int(11) NOT NULL, # user id favorite report belongs to
195 `report_spec` text default NULL, # future replacement field for all report settings
196 `client_id` int(11) default NULL, # client id (if selected)
197 `cf_1_option_id` int(11) default NULL, # custom field 1 option id (if selected)
198 `project_id` int(11) default NULL, # project id (if selected)
199 `task_id` int(11) default NULL, # task id (if selected)
200 `billable` tinyint(4) default NULL, # whether to include billable, not billable, or all records
201 `invoice` tinyint(4) default NULL, # whether to include invoiced, not invoiced, or all records
202 `paid_status` tinyint(4) default NULL, # whether to include paid, not paid, or all records
203 `users` text default NULL, # Comma-separated list of user ids. Nothing here means "all" users.
204 `period` tinyint(4) default NULL, # selected period type for report
205 `period_start` date default NULL, # period start
206 `period_end` date default NULL, # period end
207 `show_client` tinyint(4) NOT NULL default 0, # whether to show client column
208 `show_invoice` tinyint(4) NOT NULL default 0, # whether to show invoice column
209 `show_paid` tinyint(4) NOT NULL default 0, # whether to show paid column
210 `show_project` tinyint(4) NOT NULL default 0, # whether to show project column
211 `show_start` tinyint(4) NOT NULL default 0, # whether to show start field
212 `show_duration` tinyint(4) NOT NULL default 0, # whether to show duration field
213 `show_cost` tinyint(4) NOT NULL default 0, # whether to show cost field
214 `show_task` tinyint(4) NOT NULL default 0, # whether to show task column
215 `show_end` tinyint(4) NOT NULL default 0, # whether to show end field
216 `show_note` tinyint(4) NOT NULL default 0, # whether to show note column
217 `show_custom_field_1` tinyint(4) NOT NULL default 0, # whether to show custom field 1
218 `show_totals_only` tinyint(4) NOT NULL default 0, # whether to show totals only
219 `group_by` varchar(20) default NULL, # group by field
220 `status` tinyint(4) default 1, # favorite report status
226 # Structure for table tt_cron. It is used to email favorite reports on schedule.
228 CREATE TABLE `tt_cron` (
229 `id` int(11) NOT NULL auto_increment, # entry id
230 `team_id` int(11) NOT NULL, # team id
231 `cron_spec` varchar(255) NOT NULL, # cron specification, "0 1 * * *" for "daily at 01:00"
232 `last` int(11) default NULL, # UNIX timestamp of when job was last run
233 `next` int(11) default NULL, # UNIX timestamp of when to run next job
234 `report_id` int(11) default NULL, # report id from tt_fav_reports, a report to mail on schedule
235 `email` varchar(100) default NULL, # email to send results to
236 `cc` varchar(100) default NULL, # cc email to send results to
237 `subject` varchar(100) default NULL, # email subject
238 `report_condition` varchar(255) default NULL, # report condition, "count > 0" for sending not empty reports
239 `status` tinyint(4) default 1, # entry status
245 # Structure for table tt_clients. A client is an entity for whom work is performed and who may be invoiced.
247 CREATE TABLE `tt_clients` (
248 `id` int(11) NOT NULL AUTO_INCREMENT, # client id
249 `team_id` int(11) NOT NULL, # team id
250 `name` varchar(80) COLLATE utf8_bin NOT NULL, # client name
251 `address` varchar(255) default NULL, # client address
252 `tax` float(6,2) default '0.00', # applicable tax for this client
253 `projects` text default NULL, # comma-separated list of project ids assigned to this client
254 `status` tinyint(4) default 1, # client status
258 # Create an index that guarantees unique active and inactive clients per team.
259 create unique index client_name_idx on tt_clients(team_id, name, status);
263 # Structure for table tt_client_project_binds. This table maps clients to assigned projects.
265 CREATE TABLE `tt_client_project_binds` (
266 `client_id` int(11) NOT NULL, # client id
267 `project_id` int(11) NOT NULL # project id
270 # Indexes for tt_client_project_binds.
271 create index client_idx on tt_client_project_binds(client_id);
272 create index project_idx on tt_client_project_binds(project_id);
276 # Structure for table tt_config. This table is used to store configuration info for users.
277 # For example, last_report_email parameter stores an email for user last report was emailed to.
279 CREATE TABLE `tt_config` (
280 `user_id` int(11) NOT NULL, # user id
281 `param_name` varchar(32) NOT NULL, # parameter name
282 `param_value` varchar(80) default NULL # parameter value
285 # Create an index that guarantees unique parameter names per user.
286 create unique index param_idx on tt_config(user_id, param_name);
289 # Below are the tables used by CustomFields plugin.
292 # Structure for table tt_custom_fields. This table contains definitions of custom fields.
294 CREATE TABLE `tt_custom_fields` (
295 `id` int(11) NOT NULL auto_increment, # custom field id
296 `team_id` int(11) NOT NULL, # team id
297 `type` tinyint(4) NOT NULL default 0, # custom field type (text or dropdown)
298 `label` varchar(32) NOT NULL default '', # custom field label
299 `required` tinyint(4) default 0, # whether this custom field is mandatory for time records
300 `status` tinyint(4) default 1, # custom field status
306 # Structure for table tt_custom_field_options. This table defines options for dropdown custom fields.
308 CREATE TABLE `tt_custom_field_options` (
309 `id` int(11) NOT NULL auto_increment, # option id
310 `field_id` int(11) NOT NULL, # custom field id
311 `value` varchar(32) NOT NULL default '', # option value
317 # Structure for table tt_custom_field_log.
318 # This table supplements tt_log and contains custom field values for records.
320 CREATE TABLE `tt_custom_field_log` (
321 `id` bigint NOT NULL auto_increment, # cutom field log id
322 `log_id` bigint NOT NULL, # id of a record in tt_log this record corresponds to
323 `field_id` int(11) NOT NULL, # custom field id
324 `option_id` int(11) default NULL, # Option id. Used for dropdown custom fields.
325 `value` varchar(255) default NULL, # Text value. Used for text custom fields.
326 `status` tinyint(4) default 1, # custom field log entry status
332 # Structure for table tt_expense_items.
333 # This table lists expense items.
335 CREATE TABLE `tt_expense_items` (
336 `id` bigint NOT NULL auto_increment, # expense item id
337 `date` date NOT NULL, # date the record is for
338 `user_id` int(11) NOT NULL, # user id the expense item is reported by
339 `client_id` int(11) default NULL, # client id
340 `project_id` int(11) default NULL, # project id
341 `name` text NOT NULL, # expense item name (what is an expense for)
342 `cost` decimal(10,2) default '0.00', # item cost (including taxes, etc.)
343 `invoice_id` int(11) default NULL, # invoice id
344 `paid` tinyint(4) default 0, # whether the item is paid
345 `status` tinyint(4) default 1, # item status
349 # Create indexes on tt_expense_items for performance.
350 create index date_idx on tt_expense_items(date);
351 create index user_idx on tt_expense_items(user_id);
352 create index client_idx on tt_expense_items(client_id);
353 create index project_idx on tt_expense_items(project_id);
354 create index invoice_idx on tt_expense_items(invoice_id);
358 # Structure for table tt_predefined_expenses.
359 # This table keeps names and costs for predefined expenses.
361 CREATE TABLE `tt_predefined_expenses` (
362 `id` int(11) NOT NULL auto_increment, # predefined expense id
363 `team_id` int(11) NOT NULL, # team id
364 `name` varchar(255) NOT NULL, # predefined expense name, such as mileage
365 `cost` decimal(10,2) default '0.00', # cost for one unit
371 # Structure for table tt_monthly_quotas.
372 # This table keeps monthly work hour quotas for teams.
374 CREATE TABLE `tt_monthly_quotas` (
375 `team_id` int(11) NOT NULL, # team id
376 `year` smallint(5) UNSIGNED NOT NULL, # quota year
377 `month` tinyint(3) UNSIGNED NOT NULL, # quota month
378 `minutes` int(11) default NULL, # quota in minutes in specified month and year
379 PRIMARY KEY (`team_id`,`year`,`month`)
382 ALTER TABLE `tt_monthly_quotas`
383 ADD CONSTRAINT `FK_TT_TEAM_CONSTRAING` FOREIGN KEY (`team_id`) REFERENCES `tt_teams` (`id`) ON DELETE CASCADE ON UPDATE CASCADE;
387 # Structure for table tt_roles. This table stores customized team roles.
389 CREATE TABLE `tt_roles` (
390 `id` int(11) NOT NULL auto_increment, # Role id. Identifies roles for all groups on the server.
391 `team_id` int(11) NOT NULL, # Team id the role is defined for.
392 `name` varchar(80) default NULL, # Role name - custom role name. In case we are editing a
393 # predefined role (USER, etc.), we can rename the role here.
394 `description` varchar(255) default NULL, # Role description.
395 `rank` int(11) default 0, # Role rank, an integer value between 0-324. Predefined role ranks:
396 # USER - 4, CLIENT - 16, COMANAGER - 68, MANAGER - 324.
397 # Rank is used to determine what "lesser roles" are in each group
398 # for sutuations such as "manage_users".
399 # It also identifies a role within a team (by its "rank").
400 # Value of rank is to be used in role field in tt_users table,
401 # just like standard roles now.
402 `rights` text default NULL, # Comma-separated list of rights assigned to a role.
403 # NULL here for predefined roles (4, 16, 68, 324 - manager)
404 # means a hard-coded set of default access rights.
405 `status` tinyint(4) default 1, # Role status.
409 # Create an index that guarantees unique active and inactive role ranks in each group.
410 create unique index role_idx on tt_roles(team_id, rank, status);
414 # Structure for table tt_site_config. This table stores configuration data
415 # for Time Tracker site as a whole.
416 # For example, database version, code version, site language, etc.
418 CREATE TABLE `tt_site_config` (
419 `param_name` varchar(32) NOT NULL, # parameter name
420 `param_value` text default NULL, # parameter value
421 `created` datetime default CURRENT_TIMESTAMP, # creation time
422 `updated` datetime ON UPDATE CURRENT_TIMESTAMP, # modification time
423 PRIMARY KEY (`param_name`)
426 INSERT INTO `tt_site_config` (`param_name`, `param_value`) VALUES ('version_db', '1.17.34'); # TODO: change when structure changes.