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 NOT NULL, # modification timestamp
18 `name` varchar(80) default NULL, # team name
19 `address` varchar(255) default NULL, # team address, used in invoices
20 `currency` varchar(7) default NULL, # team 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 `uncompleted_indicators` smallint(2) NOT NULL DEFAULT '0', # whether to show indicators for users with uncompleted time entries
31 `bcc_email` varchar(100) default NULL, # bcc email to copy all reports to
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_hours` smallint(6) DEFAULT '8', # number of work hours in a regular day
36 `custom_logo` tinyint(4) default '0', # whether to use a custom logo or not
37 `status` tinyint(4) default '1', # team status
43 # Structure for table tt_users. This table is used to store user properties.
45 CREATE TABLE `tt_users` (
46 `id` int(11) NOT NULL auto_increment, # user id
47 `timestamp` timestamp NOT NULL, # modification timestamp
48 `login` varchar(50) COLLATE utf8_bin NOT NULL, # user login
49 `password` varchar(50) default NULL, # password hash
50 `name` varchar(100) default NULL, # user name
51 `team_id` int(11) NOT NULL, # team id
52 `role` int(11) default '4', # user role ("manager", "co-manager", "client", or "user")
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 NOT NULL, # 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 `status` tinyint(4) default '1', # time record status
151 # Create indexes on tt_log for performance.
152 create index date_idx on tt_log(date);
153 create index user_idx on tt_log(user_id);
154 create index client_idx on tt_log(client_id);
155 create index invoice_idx on tt_log(invoice_id);
156 create index project_idx on tt_log(project_id);
157 create index task_idx on tt_log(task_id);
161 # Structure for table tt_invoices. Invoices are issued to clients for billable work.
163 CREATE TABLE `tt_invoices` (
164 `id` int(11) NOT NULL auto_increment, # invoice id
165 `team_id` int(11) NOT NULL, # team id
166 `name` varchar(80) COLLATE utf8_bin NOT NULL, # invoice name
167 `date` date NOT NULL, # invoice date
168 `client_id` int(11) NOT NULL, # client id
169 `status` tinyint(4) default '1', # invoice status
173 # Create an index that guarantees unique invoice names per team.
174 create unique index name_idx on tt_invoices(team_id, name, status);
178 # Structure for table tt_tmp_refs. Used for reset password mechanism.
180 CREATE TABLE `tt_tmp_refs` (
181 `timestamp` timestamp NOT NULL, # creation timestamp
182 `ref` char(32) NOT NULL default '', # unique reference for user, used in urls
183 `user_id` int(11) NOT NULL # user id
188 # Structure for table tt_fav_reports. Favorite reports are pre-configured report configurations.
190 CREATE TABLE `tt_fav_reports` (
191 `id` int(11) NOT NULL auto_increment, # favorite report id
192 `name` varchar(200) NOT NULL, # favorite report name
193 `user_id` int(11) NOT NULL, # user id favorite report belongs to
194 `client_id` int(11) default NULL, # client id (if selected)
195 `cf_1_option_id` int(11) default NULL, # custom field 1 option id (if selected)
196 `project_id` int(11) default NULL, # project id (if selected)
197 `task_id` int(11) default NULL, # task id (if selected)
198 `billable` tinyint(4) default NULL, # whether to include billable, not billable, or all records
199 `invoice` tinyint(4) default NULL, # whether to include invoiced, not invoiced, or all records
200 `users` text default NULL, # Comma-separated list of user ids. Nothing here means "all" users.
201 `period` tinyint(4) default NULL, # selected period type for report
202 `period_start` date default NULL, # period start
203 `period_end` date default NULL, # period end
204 `show_client` tinyint(4) NOT NULL default '0', # whether to show client column
205 `show_invoice` tinyint(4) NOT NULL default '0', # whether to show invoice column
206 `show_project` tinyint(4) NOT NULL default '0', # whether to show project column
207 `show_start` tinyint(4) NOT NULL default '0', # whether to show start field
208 `show_duration` tinyint(4) NOT NULL default '0', # whether to show duration field
209 `show_cost` tinyint(4) NOT NULL default '0', # whether to show cost field
210 `show_task` tinyint(4) NOT NULL default '0', # whether to show task column
211 `show_end` tinyint(4) NOT NULL default '0', # whether to show end field
212 `show_note` tinyint(4) NOT NULL default '0', # whether to show note column
213 `show_custom_field_1` tinyint(4) NOT NULL default '0', # whether to show custom field 1
214 `show_totals_only` tinyint(4) NOT NULL default '0', # whether to show totals only
215 `group_by` varchar(20) default NULL, # group by field
216 `status` tinyint(4) default '1', # favorite report status
222 # Structure for table tt_cron. It is used to email favorite reports on schedule.
224 CREATE TABLE `tt_cron` (
225 `id` int(11) NOT NULL auto_increment, # entry id
226 `team_id` int(11) NOT NULL, # team id
227 `cron_spec` varchar(255) NOT NULL, # cron specification, "0 1 * * *" for "daily at 01:00"
228 `last` int(11) default NULL, # UNIX timestamp of when job was last run
229 `next` int(11) default NULL, # UNIX timestamp of when to run next job
230 `report_id` int(11) default NULL, # report id from tt_fav_reports, a report to mail on schedule
231 `email` varchar(100) default NULL, # email to send results to
232 `cc` varchar(100) default NULL, # cc email to send results to
233 `subject` varchar(100) default NULL, # email subject
234 `report_condition` varchar(255) default NULL, # report condition, "count > 0" for sending not empty reports
235 `status` tinyint(4) default '1', # entry status
241 # Structure for table tt_clients. A client is an entity for whom work is performed and who may be invoiced.
243 CREATE TABLE `tt_clients` (
244 `id` int(11) NOT NULL AUTO_INCREMENT, # client id
245 `team_id` int(11) NOT NULL, # team id
246 `name` varchar(80) COLLATE utf8_bin NOT NULL, # client name
247 `address` varchar(255) default NULL, # client address
248 `tax` float(6,2) default '0.00', # applicable tax for this client
249 `projects` text default NULL, # comma-separated list of project ids assigned to this client
250 `status` tinyint(4) default '1', # client status
254 # Create an index that guarantees unique active and inactive clients per team.
255 create unique index client_name_idx on tt_clients(team_id, name, status);
259 # Structure for table tt_client_project_binds. This table maps clients to assigned projects.
261 CREATE TABLE `tt_client_project_binds` (
262 `client_id` int(11) NOT NULL, # client id
263 `project_id` int(11) NOT NULL # project id
266 # Indexes for tt_client_project_binds.
267 create index client_idx on tt_client_project_binds(client_id);
268 create index project_idx on tt_client_project_binds(project_id);
272 # Structure for table tt_config. This table is used to store configuration info for users.
273 # For example, last_report_email parameter stores an email for user last report was emailed to.
275 CREATE TABLE `tt_config` (
276 `user_id` int(11) NOT NULL, # user id
277 `param_name` varchar(32) NOT NULL, # parameter name
278 `param_value` varchar(80) default NULL # parameter value
281 # Create an index that guarantees unique parameter names per user.
282 create unique index param_idx on tt_config(user_id, param_name);
285 # Below are the tables used by CustomFields plugin.
288 # Structure for table tt_custom_fields. This table contains definitions of custom fields.
290 CREATE TABLE `tt_custom_fields` (
291 `id` int(11) NOT NULL auto_increment, # custom field id
292 `team_id` int(11) NOT NULL, # team id
293 `type` tinyint(4) NOT NULL default '0', # custom field type (text or dropdown)
294 `label` varchar(32) NOT NULL default '', # custom field label
295 `required` tinyint(4) default '0', # whether this custom field is mandatory for time records
296 `status` tinyint(4) default '1', # custom field status
302 # Structure for table tt_custom_field_options. This table defines options for dropdown custom fields.
304 CREATE TABLE `tt_custom_field_options` (
305 `id` int(11) NOT NULL auto_increment, # option id
306 `field_id` int(11) NOT NULL, # custom field id
307 `value` varchar(32) NOT NULL default '', # option value
313 # Structure for table tt_custom_field_log.
314 # This table supplements tt_log and contains custom field values for records.
316 CREATE TABLE `tt_custom_field_log` (
317 `id` bigint NOT NULL auto_increment, # cutom field log id
318 `log_id` bigint NOT NULL, # id of a record in tt_log this record corresponds to
319 `field_id` int(11) NOT NULL, # custom field id
320 `option_id` int(11) default NULL, # Option id. Used for dropdown custom fields.
321 `value` varchar(255) default NULL, # Text value. Used for text custom fields.
322 `status` tinyint(4) default '1', # custom field log entry status
328 # Structure for table tt_expense_items.
329 # This table lists expense items.
331 CREATE TABLE `tt_expense_items` (
332 `id` bigint NOT NULL auto_increment, # expense item id
333 `date` date NOT NULL, # date the record is for
334 `user_id` int(11) NOT NULL, # user id the expense item is reported by
335 `client_id` int(11) default NULL, # client id
336 `project_id` int(11) default NULL, # project id
337 `name` text NOT NULL, # expense item name (what is an expense for)
338 `cost` decimal(10,2) default '0.00', # item cost (including taxes, etc.)
339 `invoice_id` int(11) default NULL, # invoice id
340 `status` tinyint(4) default '1', # item status
344 # Create indexes on tt_expense_items for performance.
345 create index date_idx on tt_expense_items(date);
346 create index user_idx on tt_expense_items(user_id);
347 create index client_idx on tt_expense_items(client_id);
348 create index project_idx on tt_expense_items(project_id);
349 create index invoice_idx on tt_expense_items(invoice_id);
353 # Structure for table tt_predefined_expenses.
354 # This table keeps names and costs for predefined expenses.
356 CREATE TABLE `tt_predefined_expenses` (
357 `id` int(11) NOT NULL auto_increment, # predefined expense id
358 `team_id` int(11) NOT NULL, # team id
359 `name` varchar(255) NOT NULL, # predefined expense name, such as mileage
360 `cost` decimal(10,2) default '0.00', # cost for one unit
366 # Structure for table tt_monthly_quotas.
367 # This table keeps monthly work hour quotas for teams.
369 CREATE TABLE `tt_monthly_quotas` (
370 `team_id` int(11) NOT NULL, # team id
371 `year` smallint(5) UNSIGNED NOT NULL, # quota year
372 `month` tinyint(3) UNSIGNED NOT NULL, # quota month
373 `quota` smallint(5) UNSIGNED NOT NULL, # number of work hours in specified month and year
374 PRIMARY KEY (`team_id`,`year`,`month`)
377 ALTER TABLE `tt_monthly_quotas`
378 ADD CONSTRAINT `FK_TT_TEAM_CONSTRAING` FOREIGN KEY (`team_id`) REFERENCES `tt_teams` (`id`) ON DELETE CASCADE ON UPDATE CASCADE;