Skip to content

Instantly share code, notes, and snippets.

@arif98741
Last active January 30, 2025 06:00
Show Gist options
  • Save arif98741/6b7e8670944829222e84c3615a56780a to your computer and use it in GitHub Desktop.
Save arif98741/6b7e8670944829222e84c3615a56780a to your computer and use it in GitHub Desktop.
Attendance Table view QUery by Column and Row MySQL
SET @sql = NULL;
SET SESSION group_concat_max_len = 1000000;
SELECT
GROUP_CONCAT(DISTINCT
CONCAT(
'max(CASE WHEN ca.date = ''',
date_format(date, '%Y-%m-%d'),
''' THEN coalesce(p.status, ''P'') END) AS `',
date_format(date, '%Y-%m-%d'), '`'
)
) INTO @sql
FROM calendar
where date>='2025-01-01'
and date <= '2025-01-31';
SET @sql
= CONCAT('SELECT ca.studentname,
ca.rollno,
ca.class, ', @sql, '
from
(
select c.date, a.studentname, a.rollno, a.class
from calendar c
cross join tbl_admission a
) ca
left join tbl_absentees p
on ca.rollno = p.rollno
and ca.date = p.date
where ca.date>=''2025-01-01''
and ca.date <= ''2025-01-31''
group by ca.studentname, ca.rollno, ca.class
order by ca.rollno');
PREPARE stmt FROM @sql;
EXECUTE stmt;
DEALLOCATE PREPARE stmt;
SET @sql = NULL;
SET SESSION group_concat_max_len = 1000000;
-- Generate the dynamic part for each date
SELECT
GROUP_CONCAT(DISTINCT
CONCAT(
'max(CASE WHEN ca.date = ''',
date_format(date, '%Y-%m-%d'),
''' THEN coalesce(p.status, ''P'') END) AS `',
date_format(date, '%Y-%m-%d'), '`'
)
) INTO @sql
FROM calendar
WHERE date >= '2025-01-01'
AND date <= '2025-01-31';
-- Concatenate the dynamic part into the full SQL query with additional columns for total_P and total_A
SET @sql = CONCAT(
'SELECT ca.studentname,
ca.rollno,
ca.class, ', @sql, ',
SUM(CASE WHEN p.status = ''P'' OR p.status IS NULL THEN 1 ELSE 0 END) AS total_P,
SUM(CASE WHEN p.status = ''A'' THEN 1 ELSE 0 END) AS total_A
FROM (
SELECT c.date, a.studentname, a.rollno, a.class
FROM calendar c
CROSS JOIN tbl_admission a
WHERE c.date >= ''2025-01-01'' AND c.date <= ''2025-01-31''
) ca
LEFT JOIN tbl_absentees p
ON ca.rollno = p.rollno
AND ca.date = p.date
GROUP BY ca.studentname, ca.rollno, ca.class
ORDER BY ca.rollno'
);
-- Debugging: Check the generated SQL query (optional step to see the query)
-- SELECT @sql;
-- Prepare and execute the dynamic query
PREPARE stmt FROM @sql;
EXECUTE stmt;
DEALLOCATE PREPARE stmt;
-- MySQL dump 10.13 Distrib 5.7.33, for Win64 (x86_64)
--
-- Host: mysql-5eca89f-programmingmindsetbd-0062.a.aivencloud.com Database: attendance
-- ------------------------------------------------------
-- Server version 8.0.30
/*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */;
/*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */;
/*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */;
/*!40101 SET NAMES utf8 */;
/*!40103 SET @OLD_TIME_ZONE=@@TIME_ZONE */;
/*!40103 SET TIME_ZONE='+00:00' */;
/*!40014 SET @OLD_UNIQUE_CHECKS=@@UNIQUE_CHECKS, UNIQUE_CHECKS=0 */;
/*!40014 SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0 */;
/*!40101 SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='NO_AUTO_VALUE_ON_ZERO' */;
/*!40111 SET @OLD_SQL_NOTES=@@SQL_NOTES, SQL_NOTES=0 */;
SET @MYSQLDUMP_TEMP_LOG_BIN = @@SESSION.SQL_LOG_BIN;
SET @@SESSION.SQL_LOG_BIN= 0;
--
-- GTID state at the beginning of the backup
--
SET @@GLOBAL.GTID_PURGED='1f182f29-07ee-11ef-8d08-f61940eb5e8b:1-15,
3c13d2a9-e7a0-11ee-804c-6e1c6b987b62:1-147,
644bae5c-9307-11ef-9c96-bef5899b942d:1-107,
be39391d-de68-11ef-b3ea-b23ae2b13e37:1-161';
--
-- Table structure for table `calendar`
--
DROP TABLE IF EXISTS `calendar`;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `calendar` (
`ID` int NOT NULL AUTO_INCREMENT,
`Date` datetime NOT NULL,
PRIMARY KEY (`ID`)
) ENGINE=InnoDB AUTO_INCREMENT=100 DEFAULT CHARSET=latin1;
/*!40101 SET character_set_client = @saved_cs_client */;
--
-- Dumping data for table `calendar`
--
LOCK TABLES `calendar` WRITE;
/*!40000 ALTER TABLE `calendar` DISABLE KEYS */;
INSERT INTO `calendar` VALUES (1,'2013-06-01 00:00:00'),(2,'2013-06-02 00:00:00'),(3,'2013-06-03 00:00:00'),(4,'2013-06-04 00:00:00'),(5,'2013-06-05 00:00:00'),(6,'2013-06-06 00:00:00'),(7,'2013-06-07 00:00:00'),(8,'2013-06-08 00:00:00'),(9,'2013-06-09 00:00:00'),(10,'2013-06-10 00:00:00'),(11,'2013-06-11 00:00:00'),(12,'2013-06-30 00:00:00'),(13,'2013-06-12 00:00:00'),(14,'2013-06-13 00:00:00'),(15,'2013-06-14 00:00:00'),(16,'2013-06-15 00:00:00'),(17,'2013-06-16 00:00:00'),(36,'2025-01-01 00:00:00'),(37,'2025-01-02 00:00:00'),(38,'2025-01-05 00:00:00'),(39,'2025-01-06 00:00:00'),(40,'2025-01-07 00:00:00'),(41,'2025-01-08 00:00:00'),(42,'2025-01-09 00:00:00'),(43,'2025-01-12 00:00:00'),(44,'2025-01-13 00:00:00'),(45,'2025-01-14 00:00:00'),(46,'2025-01-15 00:00:00'),(47,'2025-01-16 00:00:00'),(48,'2025-01-19 00:00:00'),(49,'2025-01-20 00:00:00'),(50,'2025-01-21 00:00:00'),(51,'2025-01-22 00:00:00'),(52,'2025-01-23 00:00:00'),(53,'2025-01-26 00:00:00'),(54,'2025-01-27 00:00:00'),(55,'2025-01-28 00:00:00'),(56,'2025-01-29 00:00:00'),(57,'2025-01-31 00:00:00'),(58,'2025-02-02 00:00:00'),(59,'2025-02-03 00:00:00'),(60,'2025-02-04 00:00:00'),(61,'2025-02-05 00:00:00'),(62,'2025-02-06 00:00:00'),(63,'2025-02-09 00:00:00'),(64,'2025-02-10 00:00:00'),(65,'2025-02-11 00:00:00'),(66,'2025-02-12 00:00:00'),(67,'2025-02-13 00:00:00'),(68,'2025-02-16 00:00:00'),(69,'2025-02-17 00:00:00'),(70,'2025-02-18 00:00:00'),(71,'2025-02-19 00:00:00'),(72,'2025-02-20 00:00:00'),(73,'2025-02-23 00:00:00'),(74,'2025-02-24 00:00:00'),(75,'2025-02-25 00:00:00'),(76,'2025-02-26 00:00:00'),(77,'2025-02-27 00:00:00'),(78,'2025-03-02 00:00:00'),(79,'2025-03-03 00:00:00'),(80,'2025-03-04 00:00:00'),(81,'2025-03-05 00:00:00'),(82,'2025-03-06 00:00:00'),(83,'2025-03-09 00:00:00'),(84,'2025-03-10 00:00:00'),(85,'2025-03-11 00:00:00'),(86,'2025-03-12 00:00:00'),(87,'2025-03-13 00:00:00'),(88,'2025-03-16 00:00:00'),(89,'2025-03-17 00:00:00'),(90,'2025-03-18 00:00:00'),(91,'2025-03-19 00:00:00'),(92,'2025-03-20 00:00:00'),(93,'2025-03-23 00:00:00'),(94,'2025-03-24 00:00:00'),(95,'2025-03-25 00:00:00'),(96,'2025-03-26 00:00:00'),(97,'2025-03-27 00:00:00'),(98,'2025-03-30 00:00:00'),(99,'2025-03-31 00:00:00');
/*!40000 ALTER TABLE `calendar` ENABLE KEYS */;
UNLOCK TABLES;
--
-- Table structure for table `tbl_absentees`
--
DROP TABLE IF EXISTS `tbl_absentees`;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `tbl_absentees` (
`ID` int NOT NULL AUTO_INCREMENT,
`Date` datetime NOT NULL,
`Status` varchar(1) NOT NULL,
`RollNo` int NOT NULL,
`Class` int NOT NULL,
PRIMARY KEY (`ID`)
) ENGINE=InnoDB AUTO_INCREMENT=11 DEFAULT CHARSET=latin1;
/*!40101 SET character_set_client = @saved_cs_client */;
--
-- Dumping data for table `tbl_absentees`
--
LOCK TABLES `tbl_absentees` WRITE;
/*!40000 ALTER TABLE `tbl_absentees` DISABLE KEYS */;
INSERT INTO `tbl_absentees` VALUES (1,'2013-06-01 00:00:00','A',1,22),(2,'2013-06-01 00:00:00','A',3,22),(3,'2013-06-02 00:00:00','A',1,22),(4,'2013-06-03 00:00:00','A',1,22),(5,'2013-06-04 00:00:00','A',1,22),(6,'2013-06-01 00:00:00','A',4,22),(7,'2013-06-09 00:00:00','P',5,22),(8,'2025-01-01 00:00:00','A',5,22),(9,'2025-01-03 00:00:00','A',5,22),(10,'2025-01-05 00:00:00','A',5,22);
/*!40000 ALTER TABLE `tbl_absentees` ENABLE KEYS */;
UNLOCK TABLES;
--
-- Table structure for table `tbl_admission`
--
DROP TABLE IF EXISTS `tbl_admission`;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `tbl_admission` (
`ID` int NOT NULL AUTO_INCREMENT,
`StudentName` varchar(100) NOT NULL,
`RollNo` int NOT NULL,
`Class` int NOT NULL,
PRIMARY KEY (`ID`)
) ENGINE=InnoDB AUTO_INCREMENT=6 DEFAULT CHARSET=latin1;
/*!40101 SET character_set_client = @saved_cs_client */;
--
-- Dumping data for table `tbl_admission`
--
LOCK TABLES `tbl_admission` WRITE;
/*!40000 ALTER TABLE `tbl_admission` DISABLE KEYS */;
INSERT INTO `tbl_admission` VALUES (1,'Naren',1,22),(2,'Srinu',2,22),(3,'Blah',3,22),(4,'Ariful Islam',4,22),(5,'Kamrul Islam',5,22);
/*!40000 ALTER TABLE `tbl_admission` ENABLE KEYS */;
UNLOCK TABLES;
--
-- Dumping routines for database 'attendance'
--
SET @@SESSION.SQL_LOG_BIN = @MYSQLDUMP_TEMP_LOG_BIN;
/*!40103 SET TIME_ZONE=@OLD_TIME_ZONE */;
/*!40101 SET SQL_MODE=@OLD_SQL_MODE */;
/*!40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */;
/*!40014 SET UNIQUE_CHECKS=@OLD_UNIQUE_CHECKS */;
/*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */;
/*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */;
/*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */;
/*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */;
-- Dump completed on 2025-01-30 0:20:02
studentname rollno class 2025-01-01 2025-01-02 2025-01-03 ... 2025-01-31
John Doe 101 10A P A P ... P
Jane Smith 102 10A P P A ... A
Alice Lee 103 10B A P P ... P
Bob Brown 104 10B P A P ... A
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment