aboutsummaryrefslogtreecommitdiff
path: root/index.html
blob: e403cdc54f22b5696972e4597cd3cd74cc4d19ff (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
<!DOCTYPE html>
<html>

<head>
    <title>CU Boulder Grades Database</title>
    <script src="https://cdnjs.cloudflare.com/ajax/libs/sql.js/1.9.0/sql-wasm.js" onload integrity="sha512-PAyD/84QEfxE1X/H3RDJY9kqXtJObyGq6qA93+LnkMNWdTLHjcTKHsDOcz6Y5xAdsaMGItRP5vNs4vtj3/FRuw==" crossorigin="anonymous" referrerpolicy="no-referrer"></script>
    <link rel="stylesheet" href="https://cdn.jsdelivr.net/npm/@picocss/pico@1/css/pico.min.css">

    <meta name="viewport" content="width=device-width, initial-scale=1">
</head>

<body>
    <main class="container">
    <h1>iNeedATitle</h1>
    <p id="database-loading"><b>Loading database...</b></p>
    <form>
        <textarea id="output" rows="10" cols="80" disabled></textarea>
        <input type="text" id="query" value="SELECT COUNT(*) FROM raw_data" style="width: 100%">
        <br>
        <button type="button" value="Run Raw Query" onclick="run()" disabled>Run Raw Query</button>
    </form>
    <hr>
    <section>
    <h2>Queries</h2>
    <h3>By Instructor</h3>
    <p>Find classes, and average grade for a given instructor</p>
    <p>Since the instructor names are provided in the format <pre>Last Name, First Name</pre> It is best if you start typing the last name first.</p>
    <label for="instructor">Instructor</label>
    <input type="text" id="instructor" name="instructor" list="instructors">
    <datalist id="instructors" class="instructorDatalist">
    </datalist>
    <button type="button" onclick="getClassesByInstructor()" disabled>Get Classes & Average Grades</button>
    <form>
        <div id="table-container"></div>
    </form>
    <hr>
    <h3>By Class Code</h3>
    <p>Note: There is a space between the subject and course code. For example, "CSCI 1300"</p>
    <label for="classCode">Class Code</label>
    <input type="text" id="classCode" name="classCode" list="classCodes">
    <datalist id="classCodes" class="classCodeDatalist">
    </datalist>
    <button type="button" onclick="getClassesByClassCode()" disabled>Get Instructors & Average Grades</button>
    <form>
        <div id="table-container-class-codes"></div>
    </form>
    </section>
    <br>
    <br>
    </main>
    <script type="text/javascript">
        let SQL = undefined
        let db = undefined

        async function fetchDatabase(url) {
            const response = await fetch(url);
            if (!response.ok) {
                throw new Error(`HTTP error! status: ${response.status}`);
            }

            const blob = await response.blob();
            const buffer = await blob.arrayBuffer();
            const uInt8Array = new Uint8Array(buffer);

            db = new SQL.Database(uInt8Array);

            // populate instructors

            let query = "SELECT DISTINCT insname1 AS instructor_name FROM raw_data WHERE insname1 IS NOT NULL UNION SELECT DISTINCT insname2 FROM raw_data WHERE insname2 IS NOT NULL UNION SELECT DISTINCT insname3 FROM raw_data WHERE insname3 IS NOT NULL;"
            const results = db.exec(query);

            const result = results[0];
            const columns = result.columns;
            const rows = result.values;

            let datalist = document.getElementById("instructors");

            for (let i = 0; i < rows.length; i++) {
                let option = document.createElement("option");
                option.value = rows[i][0];
                datalist.appendChild(option);
            }

            let classCodeQuery = "SELECT DISTINCT Subject || ' ' || Course AS ClassCode FROM raw_data"
            const classCodeResults = db.exec(classCodeQuery);

            const classCodeResult = classCodeResults[0];
            const classCodeColumns = classCodeResult.columns;
            const classCodeRows = classCodeResult.values;

            let classCodeDatalist = document.getElementById("classCodes");

            for (let i = 0; i < classCodeRows.length; i++) {
                let option = document.createElement("option");
                option.value = classCodeRows[i][0];
                classCodeDatalist.appendChild(option);
            }

            document.getElementById("database-loading").textContent = "Database loaded!";
            let buttons = document.getElementsByTagName("button");
            for (let i = 0; i < buttons.length; i++) {
                buttons[i].disabled = false;
            }
            

        }

        async function loadDatabase() {
            SQL = await initSqlJs({
                locateFile: file => `https://cdnjs.cloudflare.com/ajax/libs/sql.js/1.9.0/sql-wasm.wasm`
            });
            fetchDatabase("./grades.sqlite");
        }

        loadDatabase();

        function run() {
            const query = document.getElementById("query").value;
            const results = db.exec(query);
            const result = results[0];
            const columns = result.columns;
            const rows = result.values;
            const output = document.getElementById("output");
            output.value = JSON.stringify({
                columns,
                rows
            }, null, 2);
        }

        function getClassesByInstructor() {
            let instructor = document.getElementById("instructor").value;

            let query = `SELECT  Subject || ' ' || Course as "Class", CourseTitle as "Title", GROUP_CONCAT(DISTINCT YearTerm) AS YearTerms, ROUND(AVG(AVG_GRD), 2) AS "Average Grade",  ROUND(AVG(PCT_A), 2) as "% A", ROUND(AVG(PCT_B), 2) as "% B", ROUND(AVG(PCT_C_MINUS_OR_BELOW), 2) as "% C- and below", ROUND(AVG(N_GRADE)) as "Average No. of Students" FROM raw_data AS main WHERE insname1 = "${instructor.toUpperCase()}" OR insname2 = "${instructor.toUpperCase()}" OR insname3 = "${instructor.toUpperCase()}" GROUP BY CourseTitle`
            console.log(query);

            const results = db.exec(query);
            const result = results[0];
            const columns = result.columns;
            const rows = result.values;
            const tableContainer = document.getElementById("table-container");
            const table = document.createElement("table");
            const thead = document.createElement("thead");
            const tbody = document.createElement("tbody");
            const headerRow = document.createElement("tr");

            for (let i = 0; i < columns.length; i++) {
                const headerCell = document.createElement("th");
                headerCell.textContent = columns[i];
                headerRow.appendChild(headerCell);
            }

            thead.appendChild(headerRow);

            for (let i = 0; i < rows.length; i++) {
                const row = document.createElement("tr");
                for (let j = 0; j < rows[i].length; j++) {
                    const cell = document.createElement("td");
                    if (columns[j] === "YearTerms") {
                        cell.textContent = convertYearTerm(rows[i][j]);
                    } else if (!isNaN(rows[i][j]) && rows[i][j] !== null) {
                        cell.textContent = parseFloat(rows[i][j]).toFixed(2);
                    } else {
                        cell.textContent = rows[i][j];
                    }
                    row.appendChild(cell);
                }
                tbody.appendChild(row);
            }

            table.appendChild(thead);
            table.appendChild(tbody);
            tableContainer.innerHTML = "";
            tableContainer.appendChild(table);
        }

        function getClassesByClassCode() {
            let classCode = document.getElementById("classCode").value;
            let query = `SELECT YearTerm as "Year-Term", insname1 as Instructor, AVG_GRD as "Average Grade", PCT_A as "% A", PCT_B as "% B", PCT_C_MINUS_OR_BELOW as "% C- and below", N_GRADE as "No. Graded" FROM raw_data WHERE Subject || ' ' || Course = '${classCode.toUpperCase()}';`

            const results = db.exec(query);
            const result = results[0];
            const columns = result.columns;
            const rows = result.values;
            const tableContainer = document.getElementById("table-container-class-codes");
            const table = document.createElement("table");
            const thead = document.createElement("thead");
            const tbody = document.createElement("tbody");
            const headerRow = document.createElement("tr");

            for (let i = 0; i < columns.length; i++) {
                const headerCell = document.createElement("th");
                headerCell.textContent = columns[i];
                headerRow.appendChild(headerCell);
            }

            thead.appendChild(headerRow);

            for (let i = 0; i < rows.length; i++) {
                const row = document.createElement("tr");
                for (let j = 0; j < rows[i].length; j++) {
                    const cell = document.createElement("td");
                    if (columns[j] === "Year-Term") {
                        cell.textContent = convertYearTerm(rows[i][j]);
                    } else if (!isNaN(rows[i][j]) && rows[i][j] !== null) {
                        cell.textContent = parseFloat(rows[i][j]).toFixed(2);
                    } else {
                        cell.textContent = rows[i][j];
                    }
                    row.appendChild(cell);
                }
                tbody.appendChild(row);
            }

            table.appendChild(thead);
            table.appendChild(tbody);
            tableContainer.innerHTML = "";
            tableContainer.appendChild(table);
        }

        function convertYearTerm(yearTerms) {
    // Convert yearTerms to a string if it's not
    if (typeof yearTerms !== 'string') {
        yearTerms = String(yearTerms);
    }

    return yearTerms.split(',').map(term => {
        const year = term.slice(0, 4); // Assuming the year is 2000+
        const termCode = term.slice(-1); // Getting the last character for the term
        let termName = '';
        switch (termCode) {
            case '1':
                termName = 'Spring';
                break;
            case '4':
                termName = 'Summer';
                break;
            case '7':
                termName = 'Fall';
                break;
            default:
                termName = 'Unknown';
        }
        return `${termName} ${year}`;
    }).join(', ');
}

    </script>
</body>

</html>